mirror of
https://github.com/zitadel/zitadel.git
synced 2025-08-12 01:37:31 +00:00
perf(query): reduce user query duration (#10037)
# Which Problems Are Solved The resource usage to query user(s) on the database was high and therefore could have performance impact. # How the Problems Are Solved Database queries involving the users and loginnames table were improved and an index was added for user by email query. # Additional Changes - spellchecks - updated apis on load tests # additional info needs cherry pick to v3
This commit is contained in:
@@ -2,9 +2,7 @@ package projection
|
||||
|
||||
import (
|
||||
"context"
|
||||
"strings"
|
||||
|
||||
sq "github.com/Masterminds/squirrel"
|
||||
_ "embed"
|
||||
|
||||
"github.com/zitadel/zitadel/internal/eventstore"
|
||||
old_handler "github.com/zitadel/zitadel/internal/eventstore/handler"
|
||||
@@ -58,105 +56,8 @@ const (
|
||||
LoginNamePoliciesInstanceIDCol = "instance_id"
|
||||
)
|
||||
|
||||
var (
|
||||
policyUsers = sq.Select(
|
||||
alias(
|
||||
col(usersAlias, LoginNameUserIDCol),
|
||||
LoginNameUserCol,
|
||||
),
|
||||
col(usersAlias, LoginNameUserUserNameCol),
|
||||
col(usersAlias, LoginNameUserInstanceIDCol),
|
||||
col(usersAlias, LoginNameUserResourceOwnerCol),
|
||||
alias(
|
||||
coalesce(col(policyCustomAlias, LoginNamePoliciesMustBeDomainCol), col(policyDefaultAlias, LoginNamePoliciesMustBeDomainCol)),
|
||||
LoginNamePoliciesMustBeDomainCol,
|
||||
),
|
||||
).From(alias(LoginNameUserProjectionTable, usersAlias)).
|
||||
LeftJoin(
|
||||
leftJoin(LoginNamePolicyProjectionTable, policyCustomAlias,
|
||||
eq(col(policyCustomAlias, LoginNamePoliciesResourceOwnerCol), col(usersAlias, LoginNameUserResourceOwnerCol)),
|
||||
eq(col(policyCustomAlias, LoginNamePoliciesInstanceIDCol), col(usersAlias, LoginNameUserInstanceIDCol)),
|
||||
),
|
||||
).
|
||||
LeftJoin(
|
||||
leftJoin(LoginNamePolicyProjectionTable, policyDefaultAlias,
|
||||
eq(col(policyDefaultAlias, LoginNamePoliciesIsDefaultCol), "true"),
|
||||
eq(col(policyDefaultAlias, LoginNamePoliciesInstanceIDCol), col(usersAlias, LoginNameUserInstanceIDCol)),
|
||||
),
|
||||
)
|
||||
|
||||
loginNamesTable = sq.Select(
|
||||
col(policyUsersAlias, LoginNameUserCol),
|
||||
col(policyUsersAlias, LoginNameUserUserNameCol),
|
||||
col(policyUsersAlias, LoginNameUserResourceOwnerCol),
|
||||
alias(col(policyUsersAlias, LoginNameUserInstanceIDCol),
|
||||
LoginNameInstanceIDCol),
|
||||
col(policyUsersAlias, LoginNamePoliciesMustBeDomainCol),
|
||||
alias(col(domainsAlias, LoginNameDomainNameCol),
|
||||
domainAlias),
|
||||
col(domainsAlias, LoginNameDomainIsPrimaryCol),
|
||||
).FromSelect(policyUsers, policyUsersAlias).
|
||||
LeftJoin(
|
||||
leftJoin(LoginNameDomainProjectionTable, domainsAlias,
|
||||
col(policyUsersAlias, LoginNamePoliciesMustBeDomainCol),
|
||||
eq(col(policyUsersAlias, LoginNameUserResourceOwnerCol), col(domainsAlias, LoginNameDomainResourceOwnerCol)),
|
||||
eq(col(policyUsersAlias, LoginNamePoliciesInstanceIDCol), col(domainsAlias, LoginNameDomainInstanceIDCol)),
|
||||
),
|
||||
)
|
||||
|
||||
viewStmt, _ = sq.Select(
|
||||
LoginNameUserCol,
|
||||
alias(
|
||||
whenThenElse(
|
||||
LoginNamePoliciesMustBeDomainCol,
|
||||
concat(LoginNameUserUserNameCol, "'@'", domainAlias),
|
||||
LoginNameUserUserNameCol),
|
||||
LoginNameCol),
|
||||
alias(coalesce(LoginNameDomainIsPrimaryCol, "true"),
|
||||
LoginNameIsPrimaryCol),
|
||||
LoginNameInstanceIDCol,
|
||||
).FromSelect(loginNamesTable, LoginNameTableAlias).MustSql()
|
||||
)
|
||||
|
||||
func col(table, name string) string {
|
||||
return table + "." + name
|
||||
}
|
||||
|
||||
func alias(col, alias string) string {
|
||||
return col + " AS " + alias
|
||||
}
|
||||
|
||||
func coalesce(values ...string) string {
|
||||
str := "COALESCE("
|
||||
for i, value := range values {
|
||||
if i > 0 {
|
||||
str += ", "
|
||||
}
|
||||
str += value
|
||||
}
|
||||
str += ")"
|
||||
return str
|
||||
}
|
||||
|
||||
func eq(first, second string) string {
|
||||
return first + " = " + second
|
||||
}
|
||||
|
||||
func leftJoin(table, alias, on string, and ...string) string {
|
||||
st := table + " " + alias + " ON " + on
|
||||
for _, a := range and {
|
||||
st += " AND " + a
|
||||
}
|
||||
return st
|
||||
}
|
||||
|
||||
func concat(strs ...string) string {
|
||||
return "CONCAT(" + strings.Join(strs, ", ") + ")"
|
||||
}
|
||||
|
||||
func whenThenElse(when, then, el string) string {
|
||||
return "(CASE WHEN " + when + " THEN " + then + " ELSE " + el + " END)"
|
||||
}
|
||||
//go:embed login_name_query.sql
|
||||
var loginNameViewStmt string
|
||||
|
||||
type loginNameProjection struct{}
|
||||
|
||||
@@ -170,7 +71,7 @@ func (*loginNameProjection) Name() string {
|
||||
|
||||
func (*loginNameProjection) Init() *old_handler.Check {
|
||||
return handler.NewViewCheck(
|
||||
viewStmt,
|
||||
loginNameViewStmt,
|
||||
handler.NewSuffixedTable(
|
||||
[]*handler.InitColumn{
|
||||
handler.NewColumn(LoginNameUserIDCol, handler.ColumnTypeText),
|
||||
@@ -229,7 +130,9 @@ func (*loginNameProjection) Init() *old_handler.Check {
|
||||
},
|
||||
handler.NewPrimaryKey(LoginNamePoliciesInstanceIDCol, LoginNamePoliciesResourceOwnerCol),
|
||||
loginNamePolicySuffix,
|
||||
handler.WithIndex(handler.NewIndex("is_default", []string{LoginNamePoliciesResourceOwnerCol, LoginNamePoliciesIsDefaultCol})),
|
||||
// this index is not used anymore, but kept for understanding why the default exists on existing systems, TODO: remove in login_names4
|
||||
// handler.WithIndex(handler.NewIndex("is_default", []string{LoginNamePoliciesResourceOwnerCol, LoginNamePoliciesIsDefaultCol})),
|
||||
handler.WithIndex(handler.NewIndex("is_default_owner", []string{LoginNamePoliciesInstanceIDCol, LoginNamePoliciesIsDefaultCol, LoginNamePoliciesResourceOwnerCol}, handler.WithInclude(LoginNamePoliciesMustBeDomainCol))),
|
||||
),
|
||||
)
|
||||
}
|
||||
|
35
internal/query/projection/login_name_query.sql
Normal file
35
internal/query/projection/login_name_query.sql
Normal file
@@ -0,0 +1,35 @@
|
||||
SELECT
|
||||
u.id AS user_id
|
||||
, CASE
|
||||
WHEN p.must_be_domain THEN CONCAT(u.user_name, '@', d.name)
|
||||
ELSE u.user_name
|
||||
END AS login_name
|
||||
, COALESCE(d.is_primary, TRUE) AS is_primary
|
||||
, u.instance_id
|
||||
FROM
|
||||
projections.login_names3_users AS u
|
||||
LEFT JOIN LATERAL (
|
||||
SELECT
|
||||
must_be_domain
|
||||
, is_default
|
||||
FROM
|
||||
projections.login_names3_policies AS p
|
||||
WHERE
|
||||
(
|
||||
p.instance_id = u.instance_id
|
||||
AND NOT p.is_default
|
||||
AND p.resource_owner = u.resource_owner
|
||||
) OR (
|
||||
p.instance_id = u.instance_id
|
||||
AND p.is_default
|
||||
)
|
||||
ORDER BY
|
||||
p.is_default -- custom first
|
||||
LIMIT 1
|
||||
) AS p ON TRUE
|
||||
LEFT JOIN
|
||||
projections.login_names3_domains d
|
||||
ON
|
||||
p.must_be_domain
|
||||
AND u.resource_owner = d.resource_owner
|
||||
AND u.instance_id = d.instance_id
|
@@ -124,6 +124,7 @@ func (*userProjection) Init() *old_handler.Check {
|
||||
handler.NewPrimaryKey(HumanUserInstanceIDCol, HumanUserIDCol),
|
||||
UserHumanSuffix,
|
||||
handler.WithForeignKey(handler.NewForeignKeyOfPublicKeys()),
|
||||
handler.WithIndex(handler.NewIndex("email", []string{HumanUserInstanceIDCol, "LOWER(" + HumanEmailCol + ")"})),
|
||||
),
|
||||
handler.NewSuffixedTable([]*handler.InitColumn{
|
||||
handler.NewColumn(MachineUserIDCol, handler.ColumnTypeText),
|
||||
|
Reference in New Issue
Block a user