Skip to content

Commit 4df1382

Browse files
authored
perf(query): reduce user query duration (zitadel#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
1 parent 647b3b5 commit 4df1382

26 files changed

+225
-689
lines changed

cmd/setup/58.go

Lines changed: 49 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,49 @@
1+
package setup
2+
3+
import (
4+
"context"
5+
"database/sql"
6+
"embed"
7+
"fmt"
8+
9+
"github.com/zitadel/logging"
10+
11+
"github.com/zitadel/zitadel/internal/database"
12+
"github.com/zitadel/zitadel/internal/eventstore"
13+
)
14+
15+
var (
16+
//go:embed 58/*.sql
17+
replaceLoginNames3View embed.FS
18+
)
19+
20+
type ReplaceLoginNames3View struct {
21+
dbClient *database.DB
22+
}
23+
24+
func (mig *ReplaceLoginNames3View) Execute(ctx context.Context, _ eventstore.Event) error {
25+
var exists bool
26+
err := mig.dbClient.QueryRowContext(ctx, func(r *sql.Row) error {
27+
return r.Scan(&exists)
28+
}, "SELECT exists(SELECT 1 from information_schema.views WHERE table_schema = 'projections' AND table_name = 'login_names3')")
29+
30+
if err != nil || !exists {
31+
return err
32+
}
33+
34+
statements, err := readStatements(replaceLoginNames3View, "58")
35+
if err != nil {
36+
return err
37+
}
38+
for _, stmt := range statements {
39+
logging.WithFields("file", stmt.file, "migration", mig.String()).Info("execute statement")
40+
if _, err := mig.dbClient.ExecContext(ctx, stmt.query); err != nil {
41+
return fmt.Errorf("%s %s: %w", mig.String(), stmt.file, err)
42+
}
43+
}
44+
return nil
45+
}
46+
47+
func (mig *ReplaceLoginNames3View) String() string {
48+
return "58_replace_login_names3_view"
49+
}
Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,36 @@
1+
CREATE OR REPLACE VIEW projections.login_names3 AS
2+
SELECT
3+
u.id AS user_id
4+
, CASE
5+
WHEN p.must_be_domain THEN CONCAT(u.user_name, '@', d.name)
6+
ELSE u.user_name
7+
END AS login_name
8+
, COALESCE(d.is_primary, TRUE) AS is_primary
9+
, u.instance_id
10+
FROM
11+
projections.login_names3_users AS u
12+
LEFT JOIN LATERAL (
13+
SELECT
14+
must_be_domain
15+
, is_default
16+
FROM
17+
projections.login_names3_policies AS p
18+
WHERE
19+
(
20+
p.instance_id = u.instance_id
21+
AND NOT p.is_default
22+
AND p.resource_owner = u.resource_owner
23+
) OR (
24+
p.instance_id = u.instance_id
25+
AND p.is_default
26+
)
27+
ORDER BY
28+
p.is_default -- custom first
29+
LIMIT 1
30+
) AS p ON TRUE
31+
LEFT JOIN
32+
projections.login_names3_domains d
33+
ON
34+
p.must_be_domain
35+
AND u.resource_owner = d.resource_owner
36+
AND u.instance_id = d.instance_id

cmd/setup/58/02_create_index.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
CREATE INDEX CONCURRENTLY IF NOT EXISTS login_names3_policies_is_default_owner_idx ON projections.login_names3_policies (instance_id, is_default, resource_owner) INCLUDE (must_be_domain)

cmd/setup/config.go

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -154,6 +154,7 @@ type Steps struct {
154154
s55ExecutionHandlerStart *ExecutionHandlerStart
155155
s56IDPTemplate6SAMLFederatedLogout *IDPTemplate6SAMLFederatedLogout
156156
s57CreateResourceCounts *CreateResourceCounts
157+
s58ReplaceLoginNames3View *ReplaceLoginNames3View
157158
}
158159

159160
func MustNewSteps(v *viper.Viper) *Steps {

cmd/setup/setup.go

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -216,6 +216,7 @@ func Setup(ctx context.Context, config *Config, steps *Steps, masterKey string)
216216
steps.s55ExecutionHandlerStart = &ExecutionHandlerStart{dbClient: dbClient}
217217
steps.s56IDPTemplate6SAMLFederatedLogout = &IDPTemplate6SAMLFederatedLogout{dbClient: dbClient}
218218
steps.s57CreateResourceCounts = &CreateResourceCounts{dbClient: dbClient}
219+
steps.s58ReplaceLoginNames3View = &ReplaceLoginNames3View{dbClient: dbClient}
219220

220221
err = projection.Create(ctx, dbClient, eventstoreClient, config.Projections, nil, nil, nil)
221222
logging.OnError(err).Fatal("unable to start projections")
@@ -262,6 +263,7 @@ func Setup(ctx context.Context, config *Config, steps *Steps, masterKey string)
262263
steps.s55ExecutionHandlerStart,
263264
steps.s56IDPTemplate6SAMLFederatedLogout,
264265
steps.s57CreateResourceCounts,
266+
steps.s58ReplaceLoginNames3View,
265267
} {
266268
setupErr = executeMigration(ctx, eventstoreClient, step, "migration failed")
267269
if setupErr != nil {

internal/query/oidc_settings.go

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -84,7 +84,7 @@ func (q *Queries) OIDCSettingsByAggID(ctx context.Context, aggregateID string) (
8484
OIDCSettingsColumnInstanceID.identifier(): authz.GetInstance(ctx).InstanceID(),
8585
}).ToSql()
8686
if err != nil {
87-
return nil, zerrors.ThrowInternal(err, "QUERY-s9nle", "Errors.Query.SQLStatment")
87+
return nil, zerrors.ThrowInternal(err, "QUERY-s9nle", "Errors.Query.SQLStatement")
8888
}
8989

9090
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {

internal/query/org_metadata.go

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -103,7 +103,7 @@ func (q *Queries) GetOrgMetadataByKey(ctx context.Context, shouldTriggerBulk boo
103103
}
104104
stmt, args, err := query.Where(eq).ToSql()
105105
if err != nil {
106-
return nil, zerrors.ThrowInternal(err, "QUERY-aDaG2", "Errors.Query.SQLStatment")
106+
return nil, zerrors.ThrowInternal(err, "QUERY-aDaG2", "Errors.Query.SQLStatement")
107107
}
108108

109109
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {
@@ -133,7 +133,7 @@ func (q *Queries) SearchOrgMetadata(ctx context.Context, shouldTriggerBulk bool,
133133
query, scan := prepareOrgMetadataListQuery()
134134
stmt, args, err := queries.toQuery(query).Where(eq).ToSql()
135135
if err != nil {
136-
return nil, zerrors.ThrowInternal(err, "QUERY-Egbld", "Errors.Query.SQLStatment")
136+
return nil, zerrors.ThrowInternal(err, "QUERY-Egbld", "Errors.Query.SQLStatement")
137137
}
138138

139139
err = q.client.QueryContext(ctx, func(rows *sql.Rows) error {

internal/query/project.go

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -211,7 +211,7 @@ func (q *Queries) ProjectByID(ctx context.Context, shouldTriggerBulk bool, id st
211211
}
212212
query, args, err := stmt.Where(eq).ToSql()
213213
if err != nil {
214-
return nil, zerrors.ThrowInternal(err, "QUERY-2m00Q", "Errors.Query.SQLStatment")
214+
return nil, zerrors.ThrowInternal(err, "QUERY-2m00Q", "Errors.Query.SQLStatement")
215215
}
216216

217217
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {

internal/query/project_grant.go

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -167,7 +167,7 @@ func (q *Queries) ProjectGrantByID(ctx context.Context, shouldTriggerBulk bool,
167167
}
168168
query, args, err := stmt.Where(eq).ToSql()
169169
if err != nil {
170-
return nil, zerrors.ThrowInternal(err, "QUERY-Nf93d", "Errors.Query.SQLStatment")
170+
return nil, zerrors.ThrowInternal(err, "QUERY-Nf93d", "Errors.Query.SQLStatement")
171171
}
172172

173173
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {
@@ -189,7 +189,7 @@ func (q *Queries) ProjectGrantByIDAndGrantedOrg(ctx context.Context, id, granted
189189
}
190190
query, args, err := stmt.Where(eq).ToSql()
191191
if err != nil {
192-
return nil, zerrors.ThrowInternal(err, "QUERY-MO9fs", "Errors.Query.SQLStatment")
192+
return nil, zerrors.ThrowInternal(err, "QUERY-MO9fs", "Errors.Query.SQLStatement")
193193
}
194194

195195
err = q.client.QueryRowContext(ctx, func(row *sql.Row) error {

internal/query/projection/login_name.go

Lines changed: 7 additions & 104 deletions
Original file line numberDiff line numberDiff line change
@@ -2,9 +2,7 @@ package projection
22

33
import (
44
"context"
5-
"strings"
6-
7-
sq "github.com/Masterminds/squirrel"
5+
_ "embed"
86

97
"github.com/zitadel/zitadel/internal/eventstore"
108
old_handler "github.com/zitadel/zitadel/internal/eventstore/handler"
@@ -58,105 +56,8 @@ const (
5856
LoginNamePoliciesInstanceIDCol = "instance_id"
5957
)
6058

61-
var (
62-
policyUsers = sq.Select(
63-
alias(
64-
col(usersAlias, LoginNameUserIDCol),
65-
LoginNameUserCol,
66-
),
67-
col(usersAlias, LoginNameUserUserNameCol),
68-
col(usersAlias, LoginNameUserInstanceIDCol),
69-
col(usersAlias, LoginNameUserResourceOwnerCol),
70-
alias(
71-
coalesce(col(policyCustomAlias, LoginNamePoliciesMustBeDomainCol), col(policyDefaultAlias, LoginNamePoliciesMustBeDomainCol)),
72-
LoginNamePoliciesMustBeDomainCol,
73-
),
74-
).From(alias(LoginNameUserProjectionTable, usersAlias)).
75-
LeftJoin(
76-
leftJoin(LoginNamePolicyProjectionTable, policyCustomAlias,
77-
eq(col(policyCustomAlias, LoginNamePoliciesResourceOwnerCol), col(usersAlias, LoginNameUserResourceOwnerCol)),
78-
eq(col(policyCustomAlias, LoginNamePoliciesInstanceIDCol), col(usersAlias, LoginNameUserInstanceIDCol)),
79-
),
80-
).
81-
LeftJoin(
82-
leftJoin(LoginNamePolicyProjectionTable, policyDefaultAlias,
83-
eq(col(policyDefaultAlias, LoginNamePoliciesIsDefaultCol), "true"),
84-
eq(col(policyDefaultAlias, LoginNamePoliciesInstanceIDCol), col(usersAlias, LoginNameUserInstanceIDCol)),
85-
),
86-
)
87-
88-
loginNamesTable = sq.Select(
89-
col(policyUsersAlias, LoginNameUserCol),
90-
col(policyUsersAlias, LoginNameUserUserNameCol),
91-
col(policyUsersAlias, LoginNameUserResourceOwnerCol),
92-
alias(col(policyUsersAlias, LoginNameUserInstanceIDCol),
93-
LoginNameInstanceIDCol),
94-
col(policyUsersAlias, LoginNamePoliciesMustBeDomainCol),
95-
alias(col(domainsAlias, LoginNameDomainNameCol),
96-
domainAlias),
97-
col(domainsAlias, LoginNameDomainIsPrimaryCol),
98-
).FromSelect(policyUsers, policyUsersAlias).
99-
LeftJoin(
100-
leftJoin(LoginNameDomainProjectionTable, domainsAlias,
101-
col(policyUsersAlias, LoginNamePoliciesMustBeDomainCol),
102-
eq(col(policyUsersAlias, LoginNameUserResourceOwnerCol), col(domainsAlias, LoginNameDomainResourceOwnerCol)),
103-
eq(col(policyUsersAlias, LoginNamePoliciesInstanceIDCol), col(domainsAlias, LoginNameDomainInstanceIDCol)),
104-
),
105-
)
106-
107-
viewStmt, _ = sq.Select(
108-
LoginNameUserCol,
109-
alias(
110-
whenThenElse(
111-
LoginNamePoliciesMustBeDomainCol,
112-
concat(LoginNameUserUserNameCol, "'@'", domainAlias),
113-
LoginNameUserUserNameCol),
114-
LoginNameCol),
115-
alias(coalesce(LoginNameDomainIsPrimaryCol, "true"),
116-
LoginNameIsPrimaryCol),
117-
LoginNameInstanceIDCol,
118-
).FromSelect(loginNamesTable, LoginNameTableAlias).MustSql()
119-
)
120-
121-
func col(table, name string) string {
122-
return table + "." + name
123-
}
124-
125-
func alias(col, alias string) string {
126-
return col + " AS " + alias
127-
}
128-
129-
func coalesce(values ...string) string {
130-
str := "COALESCE("
131-
for i, value := range values {
132-
if i > 0 {
133-
str += ", "
134-
}
135-
str += value
136-
}
137-
str += ")"
138-
return str
139-
}
140-
141-
func eq(first, second string) string {
142-
return first + " = " + second
143-
}
144-
145-
func leftJoin(table, alias, on string, and ...string) string {
146-
st := table + " " + alias + " ON " + on
147-
for _, a := range and {
148-
st += " AND " + a
149-
}
150-
return st
151-
}
152-
153-
func concat(strs ...string) string {
154-
return "CONCAT(" + strings.Join(strs, ", ") + ")"
155-
}
156-
157-
func whenThenElse(when, then, el string) string {
158-
return "(CASE WHEN " + when + " THEN " + then + " ELSE " + el + " END)"
159-
}
59+
//go:embed login_name_query.sql
60+
var loginNameViewStmt string
16061

16162
type loginNameProjection struct{}
16263

@@ -170,7 +71,7 @@ func (*loginNameProjection) Name() string {
17071

17172
func (*loginNameProjection) Init() *old_handler.Check {
17273
return handler.NewViewCheck(
173-
viewStmt,
74+
loginNameViewStmt,
17475
handler.NewSuffixedTable(
17576
[]*handler.InitColumn{
17677
handler.NewColumn(LoginNameUserIDCol, handler.ColumnTypeText),
@@ -229,7 +130,9 @@ func (*loginNameProjection) Init() *old_handler.Check {
229130
},
230131
handler.NewPrimaryKey(LoginNamePoliciesInstanceIDCol, LoginNamePoliciesResourceOwnerCol),
231132
loginNamePolicySuffix,
232-
handler.WithIndex(handler.NewIndex("is_default", []string{LoginNamePoliciesResourceOwnerCol, LoginNamePoliciesIsDefaultCol})),
133+
// this index is not used anymore, but kept for understanding why the default exists on existing systems, TODO: remove in login_names4
134+
// handler.WithIndex(handler.NewIndex("is_default", []string{LoginNamePoliciesResourceOwnerCol, LoginNamePoliciesIsDefaultCol})),
135+
handler.WithIndex(handler.NewIndex("is_default_owner", []string{LoginNamePoliciesInstanceIDCol, LoginNamePoliciesIsDefaultCol, LoginNamePoliciesResourceOwnerCol}, handler.WithInclude(LoginNamePoliciesMustBeDomainCol))),
233136
),
234137
)
235138
}

0 commit comments

Comments
 (0)