mirror of
https://github.com/zitadel/zitadel.git
synced 2024-12-14 11:58:02 +00:00
fb8cd18f93
# Which Problems Are Solved Some organizations / customers have the requirement, that there users regularly need to change their password. ZITADEL already had the possibility to manage a `password age policy` ( thought the API) with the maximum amount of days a password should be valid, resp. days after with the user should be warned of the upcoming expiration. The policy could not be managed though the Console UI and was not checked in the Login UI. # How the Problems Are Solved - The policy can be managed in the Console UI's settings sections on an instance and organization level. - During an authentication in the Login UI, if a policy is set with an expiry (>0) and the user's last password change exceeds the amount of days set, the user will be prompted to change their password. - The prompt message of the Login UI can be customized in the Custom Login Texts though the Console and API on the instance and each organization. - The information when the user last changed their password is returned in the Auth, Management and User V2 API. - The policy can be retrieved in the settings service as `password expiry settings`. # Additional Changes None. # Additional Context - closes #8081 --------- Co-authored-by: Tim Möhlmann <tim+github@zitadel.com>
93 lines
2.9 KiB
SQL
93 lines
2.9 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 as preferred_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.users13 u
|
|
LEFT JOIN projections.users13_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.users13_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; |