mirror of
https://github.com/zitadel/zitadel.git
synced 2025-08-12 01:37:31 +00:00
fix(query): user performance (#6537)
* start user by id * ignore debug bin * use new user by id * new sql * fix(sql): replace STRING with text for psql compatabilit * some changes * fix: correct user queries * fix tests * unify sql statements * use specific get user methods * search login name case insensitive * refactor: optimise user statements * add index * fix queries * fix: correct domain segregation * return all login names * fix queries * improve readability * query should be correct now * cleanup statements * fix username / loginname handling * fix: psql doesn't support create view if not exists * fix: create pre-release * ignore release comments * add lower fields * fix: always to lower * update to latest projection --------- Co-authored-by: Livio Spring <livio.a@gmail.com>
This commit is contained in:
@@ -17,6 +17,7 @@ import (
|
||||
)
|
||||
|
||||
const (
|
||||
// if the table name of the users or domains table is changed please update setup step 18
|
||||
LoginNameTableAlias = "login_names3"
|
||||
LoginNameProjectionTable = "projections." + LoginNameTableAlias
|
||||
LoginNameUserProjectionTable = LoginNameProjectionTable + "_" + loginNameUserSuffix
|
||||
@@ -35,14 +36,17 @@ const (
|
||||
domainsAlias = "domains"
|
||||
domainAlias = "domain"
|
||||
|
||||
loginNameUserSuffix = "users"
|
||||
LoginNameUserIDCol = "id"
|
||||
LoginNameUserUserNameCol = "user_name"
|
||||
loginNameUserSuffix = "users"
|
||||
LoginNameUserIDCol = "id"
|
||||
LoginNameUserUserNameCol = "user_name"
|
||||
// internal fields for faster search
|
||||
loginNameUserUserNameLowerCol = "user_name_lower"
|
||||
LoginNameUserResourceOwnerCol = "resource_owner"
|
||||
LoginNameUserInstanceIDCol = "instance_id"
|
||||
|
||||
loginNameDomainSuffix = "domains"
|
||||
LoginNameDomainNameCol = "name"
|
||||
loginNameDomainNameLowerCol = "name_lower"
|
||||
LoginNameDomainIsPrimaryCol = "is_primary"
|
||||
LoginNameDomainResourceOwnerCol = "resource_owner"
|
||||
LoginNameDomainInstanceIDCol = "instance_id"
|
||||
@@ -171,12 +175,16 @@ func (*loginNameProjection) Init() *old_handler.Check {
|
||||
[]*handler.InitColumn{
|
||||
handler.NewColumn(LoginNameUserIDCol, handler.ColumnTypeText),
|
||||
handler.NewColumn(LoginNameUserUserNameCol, handler.ColumnTypeText),
|
||||
// TODO: implement computed columns
|
||||
// handler.NewComputedColumn(loginNameUserUserNameLowerCol, handler.ColumnTypeText),
|
||||
handler.NewColumn(LoginNameUserResourceOwnerCol, handler.ColumnTypeText),
|
||||
handler.NewColumn(LoginNameUserInstanceIDCol, handler.ColumnTypeText),
|
||||
},
|
||||
handler.NewPrimaryKey(LoginNameUserInstanceIDCol, LoginNameUserIDCol),
|
||||
loginNameUserSuffix,
|
||||
handler.WithIndex(handler.NewIndex("resource_owner", []string{LoginNameUserResourceOwnerCol})),
|
||||
handler.WithIndex(handler.NewIndex("instance_user_name", []string{LoginNameUserInstanceIDCol, LoginNameUserUserNameCol},
|
||||
handler.WithInclude(LoginNameUserResourceOwnerCol),
|
||||
)),
|
||||
handler.WithIndex(
|
||||
handler.NewIndex("lnu_instance_ro_id", []string{LoginNameUserInstanceIDCol, LoginNameUserResourceOwnerCol, LoginNameUserIDCol},
|
||||
handler.WithInclude(
|
||||
@@ -184,16 +192,33 @@ func (*loginNameProjection) Init() *old_handler.Check {
|
||||
),
|
||||
),
|
||||
),
|
||||
// TODO: uncomment the following line when login_names4 will be created
|
||||
// handler.WithIndex(
|
||||
// handler.NewIndex("search", []string{LoginNameUserInstanceIDCol, loginNameUserUserNameLowerCol},
|
||||
// handler.WithInclude(LoginNameUserResourceOwnerCol),
|
||||
// ),
|
||||
// ),
|
||||
),
|
||||
handler.NewSuffixedTable(
|
||||
[]*handler.InitColumn{
|
||||
handler.NewColumn(LoginNameDomainNameCol, handler.ColumnTypeText),
|
||||
// TODO: implement computed columns
|
||||
// handler.NewComputedColumn(loginNameDomainNameLowerCol, handler.ColumnTypeText),
|
||||
handler.NewColumn(LoginNameDomainIsPrimaryCol, handler.ColumnTypeBool, handler.Default(false)),
|
||||
handler.NewColumn(LoginNameDomainResourceOwnerCol, handler.ColumnTypeText),
|
||||
handler.NewColumn(LoginNameDomainInstanceIDCol, handler.ColumnTypeText),
|
||||
},
|
||||
handler.NewPrimaryKey(LoginNameDomainInstanceIDCol, LoginNameDomainResourceOwnerCol, LoginNameDomainNameCol),
|
||||
loginNameDomainSuffix,
|
||||
// TODO: uncomment the following line when login_names4 will be created
|
||||
// handler.WithIndex(
|
||||
// handler.NewIndex("search", []string{LoginNameDomainInstanceIDCol, LoginNameDomainResourceOwnerCol, loginNameDomainNameLowerCol}),
|
||||
// ),
|
||||
// handler.WithIndex(
|
||||
// handler.NewIndex("search_result", []string{LoginNameDomainInstanceIDCol, LoginNameDomainResourceOwnerCol},
|
||||
// handler.WithInclude(LoginNameDomainIsPrimaryCol),
|
||||
// ),
|
||||
// ),
|
||||
),
|
||||
handler.NewSuffixedTable(
|
||||
[]*handler.InitColumn{
|
||||
|
@@ -3,6 +3,7 @@ package query
|
||||
import (
|
||||
"context"
|
||||
"database/sql"
|
||||
_ "embed"
|
||||
errs "errors"
|
||||
"strings"
|
||||
"time"
|
||||
@@ -314,7 +315,10 @@ var (
|
||||
}
|
||||
)
|
||||
|
||||
func (q *Queries) GetUserByID(ctx context.Context, shouldTriggerBulk bool, userID string, queries ...SearchQuery) (user *User, err error) {
|
||||
//go:embed user_by_id.sql
|
||||
var userByIDQuery string
|
||||
|
||||
func (q *Queries) GetUserByID(ctx context.Context, shouldTriggerBulk bool, userID string) (user *User, err error) {
|
||||
ctx, span := tracing.NewSpan(ctx)
|
||||
defer func() { span.EndWithError(err) }()
|
||||
|
||||
@@ -322,26 +326,55 @@ func (q *Queries) GetUserByID(ctx context.Context, shouldTriggerBulk bool, userI
|
||||
triggerUserProjections(ctx)
|
||||
}
|
||||
|
||||
query, scan := prepareUserQuery(ctx, q.client)
|
||||
for _, q := range queries {
|
||||
query = q.toQuery(query)
|
||||
}
|
||||
eq := sq.Eq{
|
||||
UserIDCol.identifier(): userID,
|
||||
UserInstanceIDCol.identifier(): authz.GetInstance(ctx).InstanceID(),
|
||||
}
|
||||
stmt, args, err := query.Where(eq).ToSql()
|
||||
if err != nil {
|
||||
return nil, errors.ThrowInternal(err, "QUERY-FBg21", "Errors.Query.SQLStatment")
|
||||
}
|
||||
|
||||
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {
|
||||
user, err = scan(row)
|
||||
return err
|
||||
}, stmt, args...)
|
||||
err = q.client.QueryRowContext(ctx,
|
||||
func(row *sql.Row) error {
|
||||
user, err = scanUser(row)
|
||||
return err
|
||||
},
|
||||
userByIDQuery,
|
||||
userID,
|
||||
authz.GetInstance(ctx).InstanceID(),
|
||||
)
|
||||
return user, err
|
||||
}
|
||||
|
||||
//go:embed user_by_login_name.sql
|
||||
var userByLoginNameQuery string
|
||||
|
||||
func (q *Queries) GetUserByLoginName(ctx context.Context, shouldTriggered bool, loginName string) (user *User, err error) {
|
||||
ctx, span := tracing.NewSpan(ctx)
|
||||
defer func() { span.EndWithError(err) }()
|
||||
|
||||
if shouldTriggered {
|
||||
triggerUserProjections(ctx)
|
||||
}
|
||||
|
||||
loginName = strings.ToLower(loginName)
|
||||
|
||||
username := loginName
|
||||
domainIndex := strings.LastIndex(loginName, "@")
|
||||
var domainSuffix string
|
||||
// split between the last @ (so ignore it if the login name ends with it)
|
||||
if domainIndex > 0 && domainIndex != len(loginName)-1 {
|
||||
domainSuffix = loginName[domainIndex+1:]
|
||||
username = loginName[:domainIndex]
|
||||
}
|
||||
|
||||
err = q.client.QueryRowContext(ctx,
|
||||
func(row *sql.Row) error {
|
||||
user, err = scanUser(row)
|
||||
return err
|
||||
},
|
||||
userByLoginNameQuery,
|
||||
username,
|
||||
domainSuffix,
|
||||
loginName,
|
||||
authz.GetInstance(ctx).InstanceID(),
|
||||
)
|
||||
return user, err
|
||||
}
|
||||
|
||||
// Deprecated: use either GetUserByID or GetUserByLoginName
|
||||
func (q *Queries) GetUser(ctx context.Context, shouldTriggerBulk bool, queries ...SearchQuery) (user *User, err error) {
|
||||
ctx, span := tracing.NewSpan(ctx)
|
||||
defer func() { span.EndWithError(err) }()
|
||||
@@ -441,7 +474,10 @@ func (q *Queries) GetHumanPhone(ctx context.Context, userID string, queries ...S
|
||||
return phone, err
|
||||
}
|
||||
|
||||
func (q *Queries) GetNotifyUserByID(ctx context.Context, shouldTriggered bool, userID string, queries ...SearchQuery) (user *NotifyUser, err error) {
|
||||
//go:embed user_notify_by_id.sql
|
||||
var notifyUserByIDQuery string
|
||||
|
||||
func (q *Queries) GetNotifyUserByID(ctx context.Context, shouldTriggered bool, userID string) (user *NotifyUser, err error) {
|
||||
ctx, span := tracing.NewSpan(ctx)
|
||||
defer func() { span.EndWithError(err) }()
|
||||
|
||||
@@ -449,23 +485,51 @@ func (q *Queries) GetNotifyUserByID(ctx context.Context, shouldTriggered bool, u
|
||||
triggerUserProjections(ctx)
|
||||
}
|
||||
|
||||
query, scan := prepareNotifyUserQuery(ctx, q.client)
|
||||
for _, q := range queries {
|
||||
query = q.toQuery(query)
|
||||
}
|
||||
eq := sq.Eq{
|
||||
UserIDCol.identifier(): userID,
|
||||
UserInstanceIDCol.identifier(): authz.GetInstance(ctx).InstanceID(),
|
||||
}
|
||||
stmt, args, err := query.Where(eq).ToSql()
|
||||
if err != nil {
|
||||
return nil, errors.ThrowInternal(err, "QUERY-Err3g", "Errors.Query.SQLStatment")
|
||||
err = q.client.QueryRowContext(ctx,
|
||||
func(row *sql.Row) error {
|
||||
user, err = scanNotifyUser(row)
|
||||
return err
|
||||
},
|
||||
notifyUserByIDQuery,
|
||||
userID,
|
||||
authz.GetInstance(ctx).InstanceID(),
|
||||
)
|
||||
return user, err
|
||||
}
|
||||
|
||||
//go:embed user_notify_by_login_name.sql
|
||||
var notifyUserByLoginNameQuery string
|
||||
|
||||
func (q *Queries) GetNotifyUserByLoginName(ctx context.Context, shouldTriggered bool, loginName string) (user *NotifyUser, err error) {
|
||||
ctx, span := tracing.NewSpan(ctx)
|
||||
defer func() { span.EndWithError(err) }()
|
||||
|
||||
if shouldTriggered {
|
||||
triggerUserProjections(ctx)
|
||||
}
|
||||
|
||||
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {
|
||||
user, err = scan(row)
|
||||
return err
|
||||
}, stmt, args...)
|
||||
loginName = strings.ToLower(loginName)
|
||||
|
||||
username := loginName
|
||||
domainIndex := strings.LastIndex(loginName, "@")
|
||||
var domainSuffix string
|
||||
// split between the last @ (so ignore it if the login name ends with it)
|
||||
if domainIndex > 0 && domainIndex != len(loginName)-1 {
|
||||
domainSuffix = loginName[domainIndex+1:]
|
||||
username = loginName[:domainIndex]
|
||||
}
|
||||
|
||||
err = q.client.QueryRowContext(ctx,
|
||||
func(row *sql.Row) error {
|
||||
user, err = scanNotifyUser(row)
|
||||
return err
|
||||
},
|
||||
notifyUserByLoginNameQuery,
|
||||
username,
|
||||
domainSuffix,
|
||||
loginName,
|
||||
authz.GetInstance(ctx).InstanceID(),
|
||||
)
|
||||
return user, err
|
||||
}
|
||||
|
||||
@@ -706,6 +770,95 @@ func preparePreferredLoginNamesQuery() (string, []interface{}, error) {
|
||||
).ToSql()
|
||||
}
|
||||
|
||||
func scanUser(row *sql.Row) (*User, error) {
|
||||
u := new(User)
|
||||
var count int
|
||||
preferredLoginName := sql.NullString{}
|
||||
|
||||
humanID := sql.NullString{}
|
||||
firstName := sql.NullString{}
|
||||
lastName := sql.NullString{}
|
||||
nickName := sql.NullString{}
|
||||
displayName := sql.NullString{}
|
||||
preferredLanguage := sql.NullString{}
|
||||
gender := sql.NullInt32{}
|
||||
avatarKey := sql.NullString{}
|
||||
email := sql.NullString{}
|
||||
isEmailVerified := sql.NullBool{}
|
||||
phone := sql.NullString{}
|
||||
isPhoneVerified := sql.NullBool{}
|
||||
|
||||
machineID := sql.NullString{}
|
||||
name := sql.NullString{}
|
||||
description := sql.NullString{}
|
||||
var secret *crypto.CryptoValue
|
||||
accessTokenType := sql.NullInt32{}
|
||||
|
||||
err := row.Scan(
|
||||
&u.ID,
|
||||
&u.CreationDate,
|
||||
&u.ChangeDate,
|
||||
&u.ResourceOwner,
|
||||
&u.Sequence,
|
||||
&u.State,
|
||||
&u.Type,
|
||||
&u.Username,
|
||||
&u.LoginNames,
|
||||
&preferredLoginName,
|
||||
&humanID,
|
||||
&firstName,
|
||||
&lastName,
|
||||
&nickName,
|
||||
&displayName,
|
||||
&preferredLanguage,
|
||||
&gender,
|
||||
&avatarKey,
|
||||
&email,
|
||||
&isEmailVerified,
|
||||
&phone,
|
||||
&isPhoneVerified,
|
||||
&machineID,
|
||||
&name,
|
||||
&description,
|
||||
&secret,
|
||||
&accessTokenType,
|
||||
&count,
|
||||
)
|
||||
|
||||
if err != nil || count != 1 {
|
||||
if errs.Is(err, sql.ErrNoRows) || count != 1 {
|
||||
return nil, errors.ThrowNotFound(err, "QUERY-Dfbg2", "Errors.User.NotFound")
|
||||
}
|
||||
return nil, errors.ThrowInternal(err, "QUERY-Bgah2", "Errors.Internal")
|
||||
}
|
||||
|
||||
u.PreferredLoginName = preferredLoginName.String
|
||||
|
||||
if humanID.Valid {
|
||||
u.Human = &Human{
|
||||
FirstName: firstName.String,
|
||||
LastName: lastName.String,
|
||||
NickName: nickName.String,
|
||||
DisplayName: displayName.String,
|
||||
AvatarKey: avatarKey.String,
|
||||
PreferredLanguage: language.Make(preferredLanguage.String),
|
||||
Gender: domain.Gender(gender.Int32),
|
||||
Email: domain.EmailAddress(email.String),
|
||||
IsEmailVerified: isEmailVerified.Bool,
|
||||
Phone: domain.PhoneNumber(phone.String),
|
||||
IsPhoneVerified: isPhoneVerified.Bool,
|
||||
}
|
||||
} else if machineID.Valid {
|
||||
u.Machine = &Machine{
|
||||
Name: name.String,
|
||||
Description: description.String,
|
||||
Secret: secret,
|
||||
AccessTokenType: domain.OIDCTokenType(accessTokenType.Int32),
|
||||
}
|
||||
}
|
||||
return u, nil
|
||||
}
|
||||
|
||||
func prepareUserQuery(ctx context.Context, db prepareDatabase) (sq.SelectBuilder, func(*sql.Row) (*User, error)) {
|
||||
loginNamesQuery, loginNamesArgs, err := prepareLoginNamesQuery()
|
||||
if err != nil {
|
||||
@@ -757,94 +910,7 @@ func prepareUserQuery(ctx context.Context, db prepareDatabase) (sq.SelectBuilder
|
||||
userPreferredLoginNameInstanceIDCol.identifier()+" = "+UserInstanceIDCol.identifier()+db.Timetravel(call.Took(ctx)),
|
||||
preferredLoginNameArgs...).
|
||||
PlaceholderFormat(sq.Dollar),
|
||||
func(row *sql.Row) (*User, error) {
|
||||
u := new(User)
|
||||
var count int
|
||||
preferredLoginName := sql.NullString{}
|
||||
|
||||
humanID := sql.NullString{}
|
||||
firstName := sql.NullString{}
|
||||
lastName := sql.NullString{}
|
||||
nickName := sql.NullString{}
|
||||
displayName := sql.NullString{}
|
||||
preferredLanguage := sql.NullString{}
|
||||
gender := sql.NullInt32{}
|
||||
avatarKey := sql.NullString{}
|
||||
email := sql.NullString{}
|
||||
isEmailVerified := sql.NullBool{}
|
||||
phone := sql.NullString{}
|
||||
isPhoneVerified := sql.NullBool{}
|
||||
|
||||
machineID := sql.NullString{}
|
||||
name := sql.NullString{}
|
||||
description := sql.NullString{}
|
||||
var secret *crypto.CryptoValue
|
||||
accessTokenType := sql.NullInt32{}
|
||||
|
||||
err := row.Scan(
|
||||
&u.ID,
|
||||
&u.CreationDate,
|
||||
&u.ChangeDate,
|
||||
&u.ResourceOwner,
|
||||
&u.Sequence,
|
||||
&u.State,
|
||||
&u.Type,
|
||||
&u.Username,
|
||||
&u.LoginNames,
|
||||
&preferredLoginName,
|
||||
&humanID,
|
||||
&firstName,
|
||||
&lastName,
|
||||
&nickName,
|
||||
&displayName,
|
||||
&preferredLanguage,
|
||||
&gender,
|
||||
&avatarKey,
|
||||
&email,
|
||||
&isEmailVerified,
|
||||
&phone,
|
||||
&isPhoneVerified,
|
||||
&machineID,
|
||||
&name,
|
||||
&description,
|
||||
&secret,
|
||||
&accessTokenType,
|
||||
&count,
|
||||
)
|
||||
|
||||
if err != nil || count != 1 {
|
||||
if errs.Is(err, sql.ErrNoRows) || count != 1 {
|
||||
return nil, errors.ThrowNotFound(err, "QUERY-Dfbg2", "Errors.User.NotFound")
|
||||
}
|
||||
return nil, errors.ThrowInternal(err, "QUERY-Bgah2", "Errors.Internal")
|
||||
}
|
||||
|
||||
u.PreferredLoginName = preferredLoginName.String
|
||||
|
||||
if humanID.Valid {
|
||||
u.Human = &Human{
|
||||
FirstName: firstName.String,
|
||||
LastName: lastName.String,
|
||||
NickName: nickName.String,
|
||||
DisplayName: displayName.String,
|
||||
AvatarKey: avatarKey.String,
|
||||
PreferredLanguage: language.Make(preferredLanguage.String),
|
||||
Gender: domain.Gender(gender.Int32),
|
||||
Email: domain.EmailAddress(email.String),
|
||||
IsEmailVerified: isEmailVerified.Bool,
|
||||
Phone: domain.PhoneNumber(phone.String),
|
||||
IsPhoneVerified: isPhoneVerified.Bool,
|
||||
}
|
||||
} else if machineID.Valid {
|
||||
u.Machine = &Machine{
|
||||
Name: name.String,
|
||||
Description: description.String,
|
||||
Secret: secret,
|
||||
AccessTokenType: domain.OIDCTokenType(accessTokenType.Int32),
|
||||
}
|
||||
}
|
||||
return u, nil
|
||||
}
|
||||
scanUser
|
||||
}
|
||||
|
||||
func prepareProfileQuery(ctx context.Context, db prepareDatabase) (sq.SelectBuilder, func(*sql.Row) (*Profile, error)) {
|
||||
@@ -1055,88 +1121,90 @@ func prepareNotifyUserQuery(ctx context.Context, db prepareDatabase) (sq.SelectB
|
||||
userPreferredLoginNameInstanceIDCol.identifier()+" = "+UserInstanceIDCol.identifier()+db.Timetravel(call.Took(ctx)),
|
||||
preferredLoginNameArgs...).
|
||||
PlaceholderFormat(sq.Dollar),
|
||||
func(row *sql.Row) (*NotifyUser, error) {
|
||||
u := new(NotifyUser)
|
||||
var count int
|
||||
loginNames := database.TextArray[string]{}
|
||||
preferredLoginName := sql.NullString{}
|
||||
scanNotifyUser
|
||||
}
|
||||
|
||||
humanID := sql.NullString{}
|
||||
firstName := sql.NullString{}
|
||||
lastName := sql.NullString{}
|
||||
nickName := sql.NullString{}
|
||||
displayName := sql.NullString{}
|
||||
preferredLanguage := sql.NullString{}
|
||||
gender := sql.NullInt32{}
|
||||
avatarKey := sql.NullString{}
|
||||
func scanNotifyUser(row *sql.Row) (*NotifyUser, error) {
|
||||
u := new(NotifyUser)
|
||||
var count int
|
||||
loginNames := database.TextArray[string]{}
|
||||
preferredLoginName := sql.NullString{}
|
||||
|
||||
notifyUserID := sql.NullString{}
|
||||
notifyEmail := sql.NullString{}
|
||||
notifyVerifiedEmail := sql.NullString{}
|
||||
notifyPhone := sql.NullString{}
|
||||
notifyVerifiedPhone := sql.NullString{}
|
||||
notifyPasswordSet := sql.NullBool{}
|
||||
humanID := sql.NullString{}
|
||||
firstName := sql.NullString{}
|
||||
lastName := sql.NullString{}
|
||||
nickName := sql.NullString{}
|
||||
displayName := sql.NullString{}
|
||||
preferredLanguage := sql.NullString{}
|
||||
gender := sql.NullInt32{}
|
||||
avatarKey := sql.NullString{}
|
||||
|
||||
err := row.Scan(
|
||||
&u.ID,
|
||||
&u.CreationDate,
|
||||
&u.ChangeDate,
|
||||
&u.ResourceOwner,
|
||||
&u.Sequence,
|
||||
&u.State,
|
||||
&u.Type,
|
||||
&u.Username,
|
||||
&loginNames,
|
||||
&preferredLoginName,
|
||||
&humanID,
|
||||
&firstName,
|
||||
&lastName,
|
||||
&nickName,
|
||||
&displayName,
|
||||
&preferredLanguage,
|
||||
&gender,
|
||||
&avatarKey,
|
||||
¬ifyUserID,
|
||||
¬ifyEmail,
|
||||
¬ifyVerifiedEmail,
|
||||
¬ifyPhone,
|
||||
¬ifyVerifiedPhone,
|
||||
¬ifyPasswordSet,
|
||||
&count,
|
||||
)
|
||||
notifyUserID := sql.NullString{}
|
||||
notifyEmail := sql.NullString{}
|
||||
notifyVerifiedEmail := sql.NullString{}
|
||||
notifyPhone := sql.NullString{}
|
||||
notifyVerifiedPhone := sql.NullString{}
|
||||
notifyPasswordSet := sql.NullBool{}
|
||||
|
||||
if err != nil || count != 1 {
|
||||
if errs.Is(err, sql.ErrNoRows) || count != 1 {
|
||||
return nil, errors.ThrowNotFound(err, "QUERY-Dgqd2", "Errors.User.NotFound")
|
||||
}
|
||||
return nil, errors.ThrowInternal(err, "QUERY-Dbwsg", "Errors.Internal")
|
||||
}
|
||||
err := row.Scan(
|
||||
&u.ID,
|
||||
&u.CreationDate,
|
||||
&u.ChangeDate,
|
||||
&u.ResourceOwner,
|
||||
&u.Sequence,
|
||||
&u.State,
|
||||
&u.Type,
|
||||
&u.Username,
|
||||
&loginNames,
|
||||
&preferredLoginName,
|
||||
&humanID,
|
||||
&firstName,
|
||||
&lastName,
|
||||
&nickName,
|
||||
&displayName,
|
||||
&preferredLanguage,
|
||||
&gender,
|
||||
&avatarKey,
|
||||
¬ifyUserID,
|
||||
¬ifyEmail,
|
||||
¬ifyVerifiedEmail,
|
||||
¬ifyPhone,
|
||||
¬ifyVerifiedPhone,
|
||||
¬ifyPasswordSet,
|
||||
&count,
|
||||
)
|
||||
|
||||
if !notifyUserID.Valid {
|
||||
return nil, errors.ThrowPreconditionFailed(nil, "QUERY-Sfw3f", "Errors.User.NotFound")
|
||||
}
|
||||
|
||||
u.LoginNames = loginNames
|
||||
if preferredLoginName.Valid {
|
||||
u.PreferredLoginName = preferredLoginName.String
|
||||
}
|
||||
if humanID.Valid {
|
||||
u.FirstName = firstName.String
|
||||
u.LastName = lastName.String
|
||||
u.NickName = nickName.String
|
||||
u.DisplayName = displayName.String
|
||||
u.AvatarKey = avatarKey.String
|
||||
u.PreferredLanguage = language.Make(preferredLanguage.String)
|
||||
u.Gender = domain.Gender(gender.Int32)
|
||||
}
|
||||
u.LastEmail = notifyEmail.String
|
||||
u.VerifiedEmail = notifyVerifiedEmail.String
|
||||
u.LastPhone = notifyPhone.String
|
||||
u.VerifiedPhone = notifyVerifiedPhone.String
|
||||
u.PasswordSet = notifyPasswordSet.Bool
|
||||
|
||||
return u, nil
|
||||
if err != nil || count != 1 {
|
||||
if errs.Is(err, sql.ErrNoRows) || count != 1 {
|
||||
return nil, errors.ThrowNotFound(err, "QUERY-Dgqd2", "Errors.User.NotFound")
|
||||
}
|
||||
return nil, errors.ThrowInternal(err, "QUERY-Dbwsg", "Errors.Internal")
|
||||
}
|
||||
|
||||
if !notifyUserID.Valid {
|
||||
return nil, errors.ThrowPreconditionFailed(nil, "QUERY-Sfw3f", "Errors.User.NotFound")
|
||||
}
|
||||
|
||||
u.LoginNames = loginNames
|
||||
if preferredLoginName.Valid {
|
||||
u.PreferredLoginName = preferredLoginName.String
|
||||
}
|
||||
if humanID.Valid {
|
||||
u.FirstName = firstName.String
|
||||
u.LastName = lastName.String
|
||||
u.NickName = nickName.String
|
||||
u.DisplayName = displayName.String
|
||||
u.AvatarKey = avatarKey.String
|
||||
u.PreferredLanguage = language.Make(preferredLanguage.String)
|
||||
u.Gender = domain.Gender(gender.Int32)
|
||||
}
|
||||
u.LastEmail = notifyEmail.String
|
||||
u.VerifiedEmail = notifyVerifiedEmail.String
|
||||
u.LastPhone = notifyPhone.String
|
||||
u.VerifiedPhone = notifyVerifiedPhone.String
|
||||
u.PasswordSet = notifyPasswordSet.Bool
|
||||
|
||||
return u, nil
|
||||
}
|
||||
|
||||
func prepareUserUniqueQuery(ctx context.Context, db prepareDatabase) (sq.SelectBuilder, func(*sql.Row) (bool, error)) {
|
||||
|
81
internal/query/user_by_id.sql
Normal file
81
internal/query/user_by_id.sql
Normal file
@@ -0,0 +1,81 @@
|
||||
WITH login_names AS (SELECT
|
||||
u.id user_id
|
||||
, u.instance_id
|
||||
, u.resource_owner
|
||||
, u.user_name
|
||||
, d.name domain_name
|
||||
, d.is_primary
|
||||
, p.must_be_domain
|
||||
, CASE WHEN p.must_be_domain
|
||||
THEN concat(u.user_name, '@', d.name)
|
||||
ELSE u.user_name
|
||||
END login_name
|
||||
FROM
|
||||
projections.login_names3_users u
|
||||
JOIN lateral (
|
||||
SELECT
|
||||
p.must_be_domain
|
||||
FROM
|
||||
projections.login_names3_policies p
|
||||
WHERE
|
||||
u.instance_id = p.instance_id
|
||||
AND (
|
||||
(p.is_default IS TRUE AND p.instance_id = $2)
|
||||
OR (p.instance_id = $2 AND p.resource_owner = u.resource_owner)
|
||||
)
|
||||
AND
|
||||
u.id = $1
|
||||
ORDER BY is_default
|
||||
LIMIT 1
|
||||
) p ON TRUE
|
||||
JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
u.instance_id = d.instance_id
|
||||
AND u.resource_owner = d.resource_owner
|
||||
)
|
||||
SELECT
|
||||
u.id
|
||||
, u.creation_date
|
||||
, u.change_date
|
||||
, u.resource_owner
|
||||
, u.sequence
|
||||
, u.state
|
||||
, u.type
|
||||
, u.username
|
||||
, (SELECT array_agg(ln.login_name)::TEXT[] login_names FROM login_names ln GROUP BY ln.user_id, ln.instance_id) login_names
|
||||
, (SELECT ln.login_name login_names_lower FROM login_names ln WHERE ln.is_primary IS TRUE) preferred_login_name
|
||||
, h.user_id
|
||||
, h.first_name
|
||||
, h.last_name
|
||||
, h.nick_name
|
||||
, h.display_name
|
||||
, h.preferred_language
|
||||
, h.gender
|
||||
, h.avatar_key
|
||||
, h.email
|
||||
, h.is_email_verified
|
||||
, h.phone
|
||||
, h.is_phone_verified
|
||||
, m.user_id
|
||||
, m.name
|
||||
, m.description
|
||||
, m.secret
|
||||
, m.access_token_type
|
||||
, count(*) OVER ()
|
||||
FROM projections.users10 u
|
||||
LEFT JOIN
|
||||
projections.users10_humans h
|
||||
ON
|
||||
u.id = h.user_id
|
||||
AND u.instance_id = h.instance_id
|
||||
LEFT JOIN
|
||||
projections.users10_machines m
|
||||
ON
|
||||
u.id = m.user_id
|
||||
AND u.instance_id = m.instance_id
|
||||
WHERE
|
||||
u.id = $1
|
||||
AND u.instance_id = $2
|
||||
LIMIT 1
|
||||
;
|
115
internal/query/user_by_login_name.sql
Normal file
115
internal/query/user_by_login_name.sql
Normal file
@@ -0,0 +1,115 @@
|
||||
WITH found_users AS (
|
||||
SELECT DISTINCT
|
||||
u.id
|
||||
, u.instance_id
|
||||
, u.resource_owner
|
||||
, u.user_name
|
||||
FROM
|
||||
projections.login_names3_users u
|
||||
JOIN lateral (
|
||||
SELECT
|
||||
p.must_be_domain
|
||||
FROM
|
||||
projections.login_names3_policies p
|
||||
WHERE
|
||||
u.instance_id = p.instance_id
|
||||
AND (
|
||||
(p.is_default IS TRUE AND p.instance_id = $4)
|
||||
OR (p.instance_id = $4 AND p.resource_owner = u.resource_owner)
|
||||
)
|
||||
AND (
|
||||
(p.must_be_domain IS TRUE AND user_name_lower = $1)
|
||||
OR (p.must_be_domain IS FALSE AND user_name_lower = $3)
|
||||
)
|
||||
ORDER BY is_default
|
||||
LIMIT 1
|
||||
) p ON TRUE
|
||||
JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
u.instance_id = d.instance_id
|
||||
AND u.resource_owner = d.resource_owner
|
||||
AND CASE WHEN p.must_be_domain THEN d.name_lower = $2 ELSE TRUE END
|
||||
),
|
||||
login_names AS (SELECT
|
||||
fu.id user_id
|
||||
, fu.instance_id
|
||||
, fu.resource_owner
|
||||
, fu.user_name
|
||||
, d.name domain_name
|
||||
, d.is_primary
|
||||
, p.must_be_domain
|
||||
, CASE WHEN p.must_be_domain
|
||||
THEN concat(fu.user_name, '@', d.name)
|
||||
ELSE fu.user_name
|
||||
END login_name
|
||||
FROM
|
||||
found_users fu
|
||||
JOIN lateral (
|
||||
SELECT
|
||||
p.must_be_domain
|
||||
FROM
|
||||
projections.login_names3_policies p
|
||||
WHERE
|
||||
fu.instance_id = p.instance_id
|
||||
AND (
|
||||
(p.is_default IS TRUE AND p.instance_id = $4)
|
||||
OR (p.instance_id = $4 AND p.resource_owner = fu.resource_owner)
|
||||
)
|
||||
ORDER BY is_default
|
||||
LIMIT 1
|
||||
) p ON TRUE
|
||||
JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
fu.instance_id = d.instance_id
|
||||
AND fu.resource_owner = d.resource_owner
|
||||
)
|
||||
SELECT
|
||||
u.id
|
||||
, u.creation_date
|
||||
, u.change_date
|
||||
, u.resource_owner
|
||||
, u.sequence
|
||||
, u.state
|
||||
, u.type
|
||||
, u.username
|
||||
, (SELECT array_agg(ln.login_name)::TEXT[] login_names FROM login_names ln WHERE fu.id = ln.user_id GROUP BY ln.user_id, ln.instance_id) login_names
|
||||
, (SELECT ln.login_name login_names_lower FROM login_names ln WHERE fu.id = ln.user_id AND ln.is_primary IS TRUE) preferred_login_name
|
||||
, h.user_id
|
||||
, h.first_name
|
||||
, h.last_name
|
||||
, h.nick_name
|
||||
, h.display_name
|
||||
, h.preferred_language
|
||||
, h.gender
|
||||
, h.avatar_key
|
||||
, h.email
|
||||
, h.is_email_verified
|
||||
, h.phone
|
||||
, h.is_phone_verified
|
||||
, m.user_id
|
||||
, m.name
|
||||
, m.description
|
||||
, m.secret
|
||||
, m.access_token_type
|
||||
, count(*) OVER ()
|
||||
FROM found_users fu
|
||||
JOIN
|
||||
projections.users10 u
|
||||
ON
|
||||
fu.id = u.id
|
||||
AND fu.instance_id = u.instance_id
|
||||
LEFT JOIN
|
||||
projections.users10_humans h
|
||||
ON
|
||||
fu.id = h.user_id
|
||||
AND fu.instance_id = h.instance_id
|
||||
LEFT JOIN
|
||||
projections.users10_machines m
|
||||
ON
|
||||
fu.id = m.user_id
|
||||
AND fu.instance_id = m.instance_id
|
||||
WHERE
|
||||
u.instance_id = $4
|
||||
;
|
79
internal/query/user_notify_by_id.sql
Normal file
79
internal/query/user_notify_by_id.sql
Normal file
@@ -0,0 +1,79 @@
|
||||
WITH login_names AS (
|
||||
SELECT
|
||||
u.id user_id
|
||||
, u.instance_id
|
||||
, u.resource_owner
|
||||
, u.user_name
|
||||
, d.name domain_name
|
||||
, d.is_primary
|
||||
, p.must_be_domain
|
||||
, CASE WHEN p.must_be_domain
|
||||
THEN concat(u.user_name, '@', d.name)
|
||||
ELSE u.user_name
|
||||
END login_name
|
||||
FROM
|
||||
projections.login_names3_users u
|
||||
JOIN lateral (
|
||||
SELECT
|
||||
p.must_be_domain
|
||||
FROM
|
||||
projections.login_names3_policies p
|
||||
WHERE
|
||||
u.instance_id = p.instance_id
|
||||
AND (
|
||||
(p.is_default IS TRUE AND p.instance_id = $2)
|
||||
OR (p.instance_id = $2 AND p.resource_owner = u.resource_owner)
|
||||
)
|
||||
AND
|
||||
u.id = $1
|
||||
ORDER BY is_default
|
||||
LIMIT 1
|
||||
) p ON TRUE
|
||||
JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
u.instance_id = d.instance_id
|
||||
AND u.resource_owner = d.resource_owner
|
||||
)
|
||||
SELECT
|
||||
u.id
|
||||
, u.creation_date
|
||||
, u.change_date
|
||||
, u.resource_owner
|
||||
, u.sequence
|
||||
, u.state
|
||||
, u.type
|
||||
, u.username
|
||||
, (SELECT array_agg(ln.login_name)::TEXT[] login_names FROM login_names ln GROUP BY ln.user_id, ln.instance_id) login_names
|
||||
, (SELECT ln.login_name login_names_lower FROM login_names ln WHERE ln.is_primary IS TRUE) preferred_login_name
|
||||
, h.user_id
|
||||
, h.first_name
|
||||
, h.last_name
|
||||
, h.nick_name
|
||||
, h.display_name
|
||||
, h.preferred_language
|
||||
, h.gender
|
||||
, h.avatar_key
|
||||
, n.user_id
|
||||
, n.last_email
|
||||
, n.verified_email
|
||||
, n.last_phone
|
||||
, n.verified_phone
|
||||
, n.password_set
|
||||
, count(*) OVER ()
|
||||
FROM projections.users10 u
|
||||
LEFT JOIN
|
||||
projections.users10_humans h
|
||||
ON
|
||||
u.id = h.user_id
|
||||
AND u.instance_id = h.instance_id
|
||||
LEFT JOIN
|
||||
projections.users10_notifications n
|
||||
ON
|
||||
u.id = n.user_id
|
||||
AND u.instance_id = n.instance_id
|
||||
WHERE
|
||||
u.id = $1
|
||||
AND u.instance_id = $2
|
||||
LIMIT 1
|
||||
;
|
112
internal/query/user_notify_by_login_name.sql
Normal file
112
internal/query/user_notify_by_login_name.sql
Normal file
@@ -0,0 +1,112 @@
|
||||
WITH found_users AS (
|
||||
SELECT DISTINCT
|
||||
u.id
|
||||
, u.instance_id
|
||||
, u.resource_owner
|
||||
, u.user_name
|
||||
FROM
|
||||
projections.login_names3_users u
|
||||
JOIN lateral (
|
||||
SELECT
|
||||
p.must_be_domain
|
||||
FROM
|
||||
projections.login_names3_policies p
|
||||
WHERE
|
||||
u.instance_id = p.instance_id
|
||||
AND (
|
||||
(p.is_default IS TRUE AND p.instance_id = $4)
|
||||
OR (p.instance_id = $4 AND p.resource_owner = u.resource_owner)
|
||||
)
|
||||
AND (
|
||||
(p.must_be_domain IS TRUE AND u.user_name_lower = $1)
|
||||
OR (p.must_be_domain IS FALSE AND u.user_name_lower = $3)
|
||||
)
|
||||
ORDER BY is_default
|
||||
LIMIT 1
|
||||
) p ON TRUE
|
||||
JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
u.instance_id = d.instance_id
|
||||
AND u.resource_owner = d.resource_owner
|
||||
AND CASE WHEN p.must_be_domain THEN d.name_lower = $2 ELSE TRUE END
|
||||
),
|
||||
login_names AS (SELECT
|
||||
fu.id user_id
|
||||
, fu.instance_id
|
||||
, fu.resource_owner
|
||||
, fu.user_name
|
||||
, d.name domain_name
|
||||
, d.is_primary
|
||||
, p.must_be_domain
|
||||
, CASE WHEN p.must_be_domain
|
||||
THEN concat(fu.user_name, '@', d.name)
|
||||
ELSE fu.user_name
|
||||
END login_name
|
||||
FROM
|
||||
found_users fu
|
||||
JOIN lateral (
|
||||
SELECT
|
||||
p.must_be_domain
|
||||
FROM
|
||||
projections.login_names3_policies p
|
||||
WHERE
|
||||
fu.instance_id = p.instance_id
|
||||
AND (
|
||||
(p.is_default IS TRUE AND p.instance_id = $4)
|
||||
OR (p.instance_id = $4 AND p.resource_owner = fu.resource_owner)
|
||||
)
|
||||
ORDER BY is_default
|
||||
LIMIT 1
|
||||
) p ON TRUE
|
||||
JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
fu.instance_id = d.instance_id
|
||||
AND fu.resource_owner = d.resource_owner
|
||||
)
|
||||
SELECT
|
||||
u.id
|
||||
, u.creation_date
|
||||
, u.change_date
|
||||
, u.resource_owner
|
||||
, u.sequence
|
||||
, u.state
|
||||
, u.type
|
||||
, u.username
|
||||
, (SELECT array_agg(ln.login_name)::TEXT[] login_names FROM login_names ln WHERE fu.id = ln.user_id GROUP BY ln.user_id, ln.instance_id) login_names
|
||||
, (SELECT ln.login_name login_names_lower FROM login_names ln WHERE fu.id = ln.user_id AND ln.is_primary IS TRUE) preferred_login_name
|
||||
, h.user_id
|
||||
, h.first_name
|
||||
, h.last_name
|
||||
, h.nick_name
|
||||
, h.display_name
|
||||
, h.preferred_language
|
||||
, h.gender
|
||||
, h.avatar_key
|
||||
, n.user_id
|
||||
, n.last_email
|
||||
, n.verified_email
|
||||
, n.last_phone
|
||||
, n.verified_phone
|
||||
, n.password_set
|
||||
, count(*) OVER ()
|
||||
FROM found_users fu
|
||||
JOIN
|
||||
projections.users10 u
|
||||
ON
|
||||
fu.id = u.id
|
||||
AND fu.instance_id = u.instance_id
|
||||
LEFT JOIN
|
||||
projections.users10_humans h
|
||||
ON
|
||||
fu.id = h.user_id
|
||||
AND fu.instance_id = h.instance_id
|
||||
LEFT JOIN
|
||||
projections.users10_notifications n
|
||||
ON
|
||||
fu.id = n.user_id
|
||||
AND fu.instance_id = n.instance_id
|
||||
WHERE
|
||||
u.instance_id = $4
|
||||
;
|
Reference in New Issue
Block a user