Files
easywish/sqlc/query.sql
Nikolai Papin 0a00a5ee2b feat: registrationBegin method without email;
fix: missing sqlc query parameter name;
feat: util for generating security codes;
feat: enums package
2025-06-23 16:23:46 +03:00

222 lines
5.8 KiB
SQL

-- vim:fileencoding=utf-8:foldmethod=marker
--: User Object {{{
;-- name: CreateUser :one
INSERT INTO users(username, verified)
VALUES ($1, false) RETURNING *;
;-- name: UpdateUser :exec
UPDATE users
SET verified = $2, deleted = $3
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: GetUserByLoginCredentials :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
--: }}}
--: 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 = $2, expires_at = $3, banned_by = $4, pardoned = $5, pardoned_by = $6
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, crypt(@password::text, gen_salt('bf')) ) RETURNING *;
;-- name: UpdateLoginInformationByUsername :exec
UPDATE login_informations
SET email = $2, password_hash = crypt(@password::text, gen_salt('bf')), totp_encrypted = $4, email_2fa_enabled = $5, password_change_date = $6
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, crypt(@code::text, gen_salt('bf'))) RETURNING *;
;-- name: GetConfirmationCodeByCode :one
SELECT * FROM confirmation_codes
WHERE user_id = $1 AND code_type = $2 AND expires_at > CURRENT_TIMESTAMP AND code_hash = crypt($3, code_hash);
;-- name: UpdateConfirmationCode :exec
UPDATE confirmation_codes
SET used = $2, deleted = $3
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 = $2, platform = $3, latest_ip = $4, login_time = $5, last_seen_date = $6, terminated = $7
WHERE id = $1;
;-- name: GetUserSessions :many
SELECT * FROM sessions
WHERE user_id = $1 AND terminated IS FALSE;
;-- 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 = $2, bio = $3, birthday = $4, avatar_url = $5, color = $6, color_grad = $7
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 = $2,
hide_profile_details = $3,
hide_for_unauthenticated = $4,
hide_birthday = $5,
hide_dates = $6,
captcha = $7,
followers_only_interaction = $8
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;
--: }}}