-- vim:fileencoding=utf-8:foldmethod=marker -- Copyright (c) 2025 Nikolai Papin -- -- This file is part of Easywish -- -- This program is free software: you can redistribute it and/or modify -- it under the terms of the GNU General Public License as published by -- the Free Software Foundation, either version 3 of the License, or -- (at your option) any later version. -- -- This program is distributed in the hope that it will be useful, -- but WITHOUT ANY WARRANTY; without even the implied warranty of -- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See -- the GNU General Public License for more details. -- -- You should have received a copy of the GNU General Public License -- along with this program. If not, see . --: User Object {{{ ;-- name: CreateUser :one INSERT INTO users(username, verified) VALUES ($1, false) RETURNING *; ;-- name: UpdateUser :exec UPDATE users SET verified = COALESCE($2, verified), deleted = COALESCE($3, deleted) WHERE id = $1; ;-- name: UpdateUserByUsername :exec UPDATE users SET verified = $2, deleted = $3 WHERE username = $1; ;-- name: DeleteUser :exec DELETE FROM users WHERE id = $1; ;-- name: DeleteUserByUsername :exec DELETE FROM users WHERE username = $1; ;-- name: GetUser :one SELECT * FROM users WHERE id = $1; ;-- name: GetUserByUsername :one SELECT * FROM users WHERE username = $1; ;-- name: GetUserByEmail :one SELECT users.* FROM users JOIN login_informations linfo ON linfo.user_id = users.id WHERE linfo.email = @email::text; ;-- name: CheckUserRegistrationAvailability :one -- SELECT -- COUNT(users.username = @username::text) > 0 AS username_busy, -- COUNT(linfo.email = @email::text) > 0 AS email_busy -- FROM users -- JOIN login_informations AS linfo on linfo.user_id = users.id -- WHERE -- ( -- users.username = @username::text OR -- linfo.email = @email::text -- ) -- AND -- ( -- users.verified IS TRUE OR -- COUNT( -- SELECT confirmation_codes as codes -- JOIN users on users.id = codes.user_id -- WHERE codes.code_type = 0 AND -- codes.deleted IS FALSE AND -- codes.expires_at < CURRENT_TIMESTAMP -- ) = 0; -- ) ;-- name: GetValidUserByLoginCredentials :one SELECT users.id, users.username, linfo.password_hash, linfo.totp_encrypted FROM users JOIN login_informations AS linfo ON users.id = linfo.user_id LEFT JOIN banned_users AS banned ON users.id = banned.user_id WHERE users.username = $1 AND users.verified IS TRUE AND -- Verified users.deleted IS FALSE AND -- Not deleted banned.user_id IS NULL AND -- Not banned linfo.password_hash = crypt(@password::text, linfo.password_hash); -- Password hash matches ;-- name: CheckUserRegistrationAvailability :one SELECT COUNT(CASE WHEN users.username = @username::text THEN 1 END) > 0 AS username_busy, COUNT(CASE WHEN linfo.email = @email::text THEN 1 END) > 0 AS email_busy FROM users JOIN login_informations AS linfo ON linfo.user_id = users.id WHERE ( users.username = @username::text OR linfo.email = @email::text ) AND ( users.verified IS TRUE OR NOT EXISTS ( SELECT 1 FROM confirmation_codes AS codes WHERE codes.user_id = users.id AND codes.code_type = 0 AND codes.deleted IS FALSE AND codes.expires_at > CURRENT_TIMESTAMP ) ); ;-- name: DeleteUnverifiedAccountsHavingUsernameOrEmail :one WITH deleted_rows AS ( DELETE FROM users WHERE (username = @username::text OR EXISTS ( SELECT 1 FROM login_informations AS linfo WHERE linfo.user_id = users.id AND linfo.email = @email::text )) AND verified IS FALSE RETURNING * ) SELECT COUNT(*) AS deleted_count FROM deleted_rows; --: }}} --: Banned User Object {{{ ;-- name: CreateBannedUser :one INSERT INTO banned_users(user_id, expires_at, reason, banned_by) VALUES ( $1, $2, $3, $4) RETURNING *; ;-- name: UpdateBannedUser :exec UPDATE banned_users SET reason = COALESCE($2, reason), expires_at = COALESCE($3, expires_at), banned_by = COALESCE($4, banned_by), pardoned = COALESCE($5, pardoned), pardoned_by = COALESCE($6, pardoned_by) WHERE id = $1; ;-- name: GetUserBans :many SELECT * FROM banned_users WHERE user_id = $1; ;-- name: GetUserBansByUsername :many SELECT banned_users.* FROM banned_users JOIN users ON users.id = banned_users.user_id WHERE users.username = $1; --: }}} --: Login Information Object {{{ ;-- name: CreateLoginInformation :one INSERT INTO login_informations(user_id, email, password_hash) VALUES ( $1, $2, @password_hash::text ) RETURNING *; ;-- name: UpdateLoginInformationByUsername :exec UPDATE login_informations SET email = COALESCE($2, email), password_hash = COALESCE(@password_hash::text, password_hash), totp_encrypted = COALESCE($4, totp_encrypted), email_2fa_enabled = COALESCE($5, email_2fa_enabled), password_change_date = COALESCE($6, password_change_date) FROM users WHERE users.username = $1 AND login_informations.user_id = users.id; ;-- name: GetLoginInformationByUsername :one SELECT login_informations.* FROM login_informations JOIN users ON users.id = login_informations.user_id WHERE users.username = $1; --: }}} --: Confirmation Code Object {{{ ;-- name: CreateConfirmationCode :one INSERT INTO confirmation_codes(user_id, code_type, code_hash) VALUES ($1, $2, @code_hash) RETURNING *; ;-- name: GetValidConfirmationCodeByCode :one SELECT * FROM confirmation_codes WHERE user_id = $1 AND code_type = $2 AND expires_at > CURRENT_TIMESTAMP AND used IS FALSE AND code_hash = crypt(@code::text, code_hash); ;-- name: GetValidConfirmationCodesByUsername :many SELECT * FROM confirmation_codes JOIN users on users.id = confirmation_codes.user_id WHERE users.username = @username::text AND code_type = @code_type::integer AND expires_at > CURRENT_TIMESTAMP AND used IS FALSE; ;-- name: UpdateConfirmationCode :exec UPDATE confirmation_codes SET used = COALESCE($2, used), deleted = COALESCE($3, deleted) WHERE id = $1; ;-- name: PruneExpiredConfirmationCodes :exec DELETE FROM confirmation_codes WHERE expires_at < CURRENT_TIMESTAMP; --: }}} -- Session Object {{{ ;-- name: CreateSession :one INSERT INTO sessions(user_id, name, platform, latest_ip) VALUES ($1, $2, $3, $4) RETURNING *; ;-- name: UpdateSession :exec UPDATE sessions SET name = COALESCE($2, name), platform = COALESCE($3, platform), latest_ip = COALESCE($4, latest_ip), login_time = COALESCE($5, login_time), last_seen_date = COALESCE($6, last_seen_date), terminated = COALESCE($7, terminated) WHERE id = $1; ;-- name: GetUserSessions :many SELECT * FROM sessions WHERE user_id = $1 AND terminated IS FALSE; ;-- name: TerminateAllSessionsForUserByUsername :exec UPDATE sessions SET terminated = TRUE FROM users WHERE sessions.user_id = users.id AND users.username = @username::text; ;-- name: PruneTerminatedSessions :exec DELETE FROM sessions WHERE terminated IS TRUE; -- }}} --: Profile Object {{{ ;-- name: CreateProfile :one INSERT INTO profiles(user_id, name, bio, birthday, avatar_url, color, color_grad) VALUES ($1, $2, $3, $4, $5, $6, $7) RETURNING *; ;-- name: UpdateProfileByUsername :exec UPDATE profiles SET name = COALESCE($2, name), bio = COALESCE($3, bio), birthday = COALESCE($4, birthday), avatar_url = COALESCE($5, avatar_url), color = COALESCE($6, color), color_grad = COALESCE($7, color_grad) FROM users WHERE username = $1; ;-- name: GetProfileByUsername :one SELECT profiles.* FROM profiles JOIN users ON users.id = profiles.user_id WHERE users.username = $1; ;-- name: GetProfileByUsernameRestricted :one SELECT users.username, profiles.name, CASE WHEN profile_settings.hide_birthday OR profile_settings.hide_profile_details THEN NULL ELSE profiles.birthday END AS birthday, CASE WHEN profile_settings.hide_profile_details THEN NULL ELSE profiles.bio END AS bio, CASE WHEN profile_settings.hide_profile_details THEN NULL ELSE profiles.avatar_url END AS avatar_url, profiles.color, profiles.color_grad, profile_settings.hide_profile_details FROM profiles JOIN users ON users.id = profiles.user_id JOIN profile_settings ON profiles.id = profile_settings.profile_id WHERE users.username = $1 AND ($2 IS FALSE OR profile_settings.hide_for_unauthenticated IS FALSE); ;-- name: GetProfilesRestricted :many SELECT users.username, profiles.name, CASE WHEN profile_settings.hide_profile_details THEN NULL ELSE profiles.avatar_url END AS avatar_url, profiles.color, profiles.color_grad, profile_settings.hide_profile_details FROM profiles JOIN users ON users.id = profiles.user_id JOIN profile_settings ON profile_settings.profile_id = profiles.id WHERE users.deleted IS FALSE AND ($2 IS FALSE OR profile_settings.hide_for_unauthenticated IS FALSE) ORDER BY profiles.id DESC LIMIT 20 OFFSET 20 * $1; --: }}} --: Profile Settings Object {{{ ;-- name: CreateProfileSettings :one INSERT INTO profile_settings(profile_id) VALUES ($1) RETURNING *; ;-- name: UpdateProfileSettings :exec UPDATE profile_settings SET hide_fulfilled = COALESCE($2, hide_fulfilled), hide_profile_details = COALESCE($3, hide_profile_details), hide_for_unauthenticated = COALESCE($4, hide_for_unauthenticated), hide_birthday = COALESCE($5, hide_birthday), hide_dates = COALESCE($6, hide_dates), captcha = COALESCE($7, captcha), followers_only_interaction = COALESCE($8, followers_only_interaction) WHERE id = $1; ;-- name: GetProfileSettingsByUsername :one SELECT profile_settings.* FROM profile_settings JOIN profiles ON profiles.id = profile_settings.profile_id JOIN users ON users.id = profiles.user_id WHERE users.username = $1; --: }}}