mirror of
https://github.com/zitadel/zitadel.git
synced 2024-12-14 20:08:02 +00:00
fb162a7d75
# Which Problems Are Solved During the implementation of #7486 it was noticed, that projections in the `auth` database schema could be blocked. Investigations suggested, that this is due to the use of [GORM](https://gorm.io/index.html) and it's inability to use an existing (sql) transaction. With the improved / simplified handling (see below) there should also be a minimal improvement in performance, resp. reduced database update statements. # How the Problems Are Solved The handlers in `auth` are exchanged to proper (sql) statements and gorm usage is removed for any writing part. To further improve / simplify the handling of the users, a new `auth.users3` table is created, where only attributes are handled, which are not yet available from the `projections.users`, `projections.login_name` and `projections.user_auth_methods` do not provide. This reduces the events handled in that specific handler by a lot. # Additional Changes None # Additional Context relates to #7486
93 lines
2.8 KiB
SQL
93 lines
2.8 KiB
SQL
WITH auth_methods AS (
|
|
SELECT
|
|
user_id
|
|
, method_type
|
|
, token_id
|
|
, state
|
|
, instance_id
|
|
, name
|
|
FROM
|
|
projections.user_auth_methods4
|
|
WHERE
|
|
instance_id = $1
|
|
AND user_id = $2
|
|
),
|
|
verified_auth_methods AS (
|
|
SELECT
|
|
method_type
|
|
FROM
|
|
auth_methods
|
|
WHERE state = 2
|
|
)
|
|
SELECT
|
|
u.id
|
|
, u.creation_date
|
|
, LEAST(u.change_date, au.change_date) AS change_date
|
|
, u.resource_owner
|
|
, u.state AS user_state
|
|
, au.password_set
|
|
, h.password_change_required
|
|
, au.password_change
|
|
, au.last_login
|
|
, u.username AS user_name
|
|
, (SELECT array_agg(ll.login_name) login_names FROM projections.login_names3 ll
|
|
WHERE u.instance_id = ll.instance_id AND u.id = ll.user_id
|
|
GROUP BY ll.user_id, ll.instance_id) AS login_names
|
|
, l.login_name
|
|
, h.first_name
|
|
, h.last_name
|
|
, h.nick_name
|
|
, h.display_name
|
|
, h.preferred_language
|
|
, h.gender
|
|
, h.email
|
|
, h.is_email_verified
|
|
, h.phone
|
|
, h.is_phone_verified
|
|
, (SELECT COALESCE((SELECT state FROM auth_methods WHERE method_type = 1), 0)) AS otp_state
|
|
, CASE
|
|
WHEN EXISTS (SELECT true FROM verified_auth_methods WHERE method_type = 3) THEN 2
|
|
WHEN EXISTS (SELECT true FROM verified_auth_methods WHERE method_type = 2) THEN 1
|
|
ELSE 0
|
|
END AS mfa_max_set_up
|
|
, au.mfa_init_skipped
|
|
, u.sequence
|
|
, au.init_required
|
|
, au.username_change_required
|
|
, m.name AS machine_name
|
|
, m.description AS machine_description
|
|
, u.type AS user_type
|
|
, (SELECT
|
|
JSONB_AGG(json_build_object('webAuthNTokenId', token_id, 'webAuthNTokenName', name, 'state', state))
|
|
FROM auth_methods
|
|
WHERE method_type = 2
|
|
) AS u2f_tokens
|
|
, (SELECT
|
|
JSONB_AGG(json_build_object('webAuthNTokenId', token_id, 'webAuthNTokenName', name, 'state', state))
|
|
FROM auth_methods
|
|
WHERE method_type = 3
|
|
) AS passwordless_tokens
|
|
, h.avatar_key
|
|
, au.passwordless_init_required
|
|
, au.password_init_required
|
|
, u.instance_id
|
|
, (SELECT EXISTS (SELECT true FROM verified_auth_methods WHERE method_type = 6)) AS otp_sms_added
|
|
, (SELECT EXISTS (SELECT true FROM verified_auth_methods WHERE method_type = 7)) AS otp_email_added
|
|
FROM projections.users12 u
|
|
LEFT JOIN projections.users12_humans h
|
|
ON u.instance_id = h.instance_id
|
|
AND u.id = h.user_id
|
|
LEFT JOIN projections.login_names3 l
|
|
ON u.instance_id = l.instance_id
|
|
AND u.id = l.user_id
|
|
AND l.is_primary = true
|
|
LEFT JOIN projections.users12_machines m
|
|
ON u.instance_id = m.instance_id
|
|
AND u.id = m.user_id
|
|
LEFT JOIN auth.users3 au
|
|
ON u.instance_id = au.instance_id
|
|
AND u.id = au.id
|
|
WHERE
|
|
u.instance_id = $1
|
|
AND u.id = $2
|
|
LIMIT 1; |