Files
archtika/rest-api/db/migrations/20240720074103_user_management_roles_jwt.sql

173 lines
4.5 KiB
MySQL
Raw Permalink Normal View History

2024-07-31 07:23:32 +02:00
-- migrate:up
CREATE EXTENSION pgcrypto;
2024-07-31 07:23:32 +02:00
CREATE EXTENSION pgjwt;
CREATE FUNCTION internal.check_role_exists ()
RETURNS TRIGGER
AS $$
2024-07-31 07:23:32 +02:00
BEGIN
IF (NOT EXISTS (
SELECT
1
FROM
pg_roles AS r
WHERE
r.rolname = NEW.user_role)) THEN
RAISE foreign_key_violation
USING message = 'Unknown database role: ' || NEW.user_role;
END IF;
RETURN NULL;
2024-07-31 07:23:32 +02:00
END
$$
LANGUAGE plpgsql;
2024-07-31 07:23:32 +02:00
CREATE CONSTRAINT TRIGGER ensure_user_role_exists
AFTER INSERT OR UPDATE ON internal.user
FOR EACH ROW
EXECUTE FUNCTION internal.check_role_exists ();
2024-07-31 07:23:32 +02:00
CREATE FUNCTION internal.encrypt_pass ()
RETURNS TRIGGER
AS $$
2024-07-31 07:23:32 +02:00
BEGIN
IF TG_OP = 'INSERT' OR NEW.password_hash != OLD.password_hash THEN
NEW.password_hash = CRYPT(NEW.password_hash, GEN_SALT('bf'));
2024-07-31 07:23:32 +02:00
END IF;
RETURN NEW;
END
$$
LANGUAGE plpgsql;
2024-07-31 07:23:32 +02:00
CREATE TRIGGER encrypt_pass
BEFORE INSERT OR UPDATE ON internal.user
FOR EACH ROW
EXECUTE FUNCTION internal.encrypt_pass ();
2024-07-31 07:23:32 +02:00
CREATE FUNCTION internal.user_role (username TEXT, pass TEXT, OUT role_name NAME)
AS $$
2024-07-31 07:23:32 +02:00
BEGIN
SELECT
u.user_role INTO role_name
FROM
internal.user AS u
WHERE
u.username = user_role.username
AND u.password_hash = CRYPT(user_role.pass, u.password_hash);
2024-07-31 07:23:32 +02:00
END;
$$
LANGUAGE plpgsql;
2024-07-31 07:23:32 +02:00
CREATE FUNCTION api.register (username TEXT, pass TEXT, OUT user_id UUID)
AS $$
2024-07-31 07:23:32 +02:00
DECLARE
_username_length_min CONSTANT INT := 3;
_username_length_max CONSTANT INT := 16;
_password_length_min CONSTANT INT := 12;
_password_length_max CONSTANT INT := 128;
BEGIN
IF (LENGTH(register.username)
NOT BETWEEN _username_length_min AND _username_length_max) THEN
RAISE string_data_length_mismatch
USING message = FORMAT('Username must be between %s and %s characters long', _username_length_min, _username_length_max);
ELSIF (EXISTS (
SELECT
1
FROM
internal.user AS u
WHERE
u.username = register.username)) THEN
RAISE unique_violation
USING message = 'Username is already taken';
ELSIF (LENGTH(register.pass)
NOT BETWEEN _password_length_min AND _password_length_max) THEN
RAISE string_data_length_mismatch
USING message = FORMAT('Password must be between %s and %s characters long', _password_length_min, _password_length_max);
ELSIF register.pass !~ '[a-z]' THEN
RAISE invalid_parameter_value
USING message = 'Password must contain at least one lowercase letter';
ELSIF register.pass !~ '[A-Z]' THEN
RAISE invalid_parameter_value
USING message = 'Password must contain at least one uppercase letter';
ELSIF register.pass !~ '[0-9]' THEN
RAISE invalid_parameter_value
USING message = 'Password must contain at least one number';
ELSIF register.pass !~ '[!@#$%^&*(),.?":{}|<>]' THEN
RAISE invalid_parameter_value
USING message = 'Password must contain at least one special character';
ELSE
INSERT INTO internal.user (username, password_hash, user_role)
SELECT
register.username,
register.pass,
CASE WHEN COUNT(*) = 0 THEN
'administrator'
ELSE
'authenticated_user'
END
FROM
internal.user
RETURNING
id INTO user_id;
END IF;
END;
$$
LANGUAGE plpgsql
SECURITY DEFINER;
2024-07-31 07:23:32 +02:00
CREATE FUNCTION api.login (username TEXT, pass TEXT, OUT token TEXT)
AS $$
2024-07-31 07:23:32 +02:00
DECLARE
_role NAME;
_user_id UUID;
_exp INT := EXTRACT(EPOCH FROM CLOCK_TIMESTAMP())::INT + 43200;
2024-07-31 07:23:32 +02:00
BEGIN
SELECT
internal.user_role (login.username, login.pass) INTO _role;
2024-07-31 07:23:32 +02:00
IF _role IS NULL THEN
RAISE invalid_password
USING message = 'Invalid username or password';
ELSE
SELECT
2024-10-03 18:51:30 +02:00
u.id INTO _user_id
FROM
internal.user AS u
WHERE
u.username = login.username;
SELECT
SIGN(JSON_BUILD_OBJECT('role', _role, 'user_id', _user_id, 'username', login.username, 'exp', _exp), CURRENT_SETTING('app.jwt_secret')) INTO token;
END IF;
2024-07-31 07:23:32 +02:00
END;
$$
LANGUAGE plpgsql
SECURITY DEFINER;
2024-07-31 07:23:32 +02:00
CREATE FUNCTION api.delete_account (pass TEXT, OUT was_deleted BOOLEAN)
AS $$
2024-07-31 07:23:32 +02:00
DECLARE
_username TEXT := CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'username';
2024-07-31 07:23:32 +02:00
_role NAME;
BEGIN
SELECT
internal.user_role (_username, delete_account.pass) INTO _role;
2024-07-31 07:23:32 +02:00
IF _role IS NULL THEN
RAISE invalid_password
USING message = 'Invalid password';
ELSE
DELETE FROM internal.user AS u
WHERE u.username = _username;
was_deleted := TRUE;
END IF;
2024-07-31 07:23:32 +02:00
END;
$$
LANGUAGE plpgsql
SECURITY DEFINER;
2024-07-31 07:23:32 +02:00
GRANT EXECUTE ON FUNCTION api.register TO anon;
2024-07-31 07:23:32 +02:00
GRANT EXECUTE ON FUNCTION api.login TO anon;
2024-07-31 07:23:32 +02:00
GRANT EXECUTE ON FUNCTION api.delete_account TO authenticated_user;
2024-07-31 07:23:32 +02:00
-- migrate:down