feat: all of sql for release 1
This commit is contained in:
205
sqlc/query.sql
205
sqlc/query.sql
@@ -1,2 +1,205 @@
|
||||
-- vim:fileencoding=utf-8:foldmethod=marker
|
||||
|
||||
--: User Object {{{
|
||||
|
||||
-- name: CreateUser :one
|
||||
INSERT INTO users(username, verified, banned, registration_date) VALUES ($1, false, false, NOW()) RETURNING id, username, verified, banned, registration_date;
|
||||
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;
|
||||
|
||||
--: }}}
|
||||
|
||||
--: 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, $3) RETURNING *;
|
||||
|
||||
-- name: UpdateLoginInformationByUsername :exec
|
||||
UPDATE login_informations
|
||||
SET email = $2, password_hash = $3, 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, expires_at)
|
||||
VALUES ($1, $2, crypt($3, gen_salt('bf')), $4) 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;
|
||||
|
||||
--: }}}
|
||||
|
||||
@@ -1,9 +1,22 @@
|
||||
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "users" (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
username VARCHAR(20) UNIQUE NOT NULL,
|
||||
verified BOOLEAN DEFAULT FALSE,
|
||||
banned BOOLEAN DEFAULT FALSE,
|
||||
registration_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
registration_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
deleted BOOLEAN DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "banned_users" (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
reason VARCHAR(512),
|
||||
expires_at TIMESTAMP,
|
||||
banned_by VARCHAR(20) DEFAULT 'system',
|
||||
pardoned BOOLEAN DEFAULT FALSE,
|
||||
pardoned_by VARCHAR(20)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "login_informations" (
|
||||
@@ -13,15 +26,14 @@ CREATE TABLE IF NOT EXISTS "login_informations" (
|
||||
password_hash VARCHAR(512) NOT NULL,
|
||||
totp_encrypted VARCHAR(512),
|
||||
email_2fa_enabled BOOLEAN DEFAULT FALSE,
|
||||
password_change_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
password_times_changed INTEGER DEFAULT 0
|
||||
password_change_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "confirmation_codes" (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
user_id BIGINT UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
type INTEGER NOT NULL,
|
||||
code VARCHAR(36) NOT NULL,
|
||||
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
code_type INTEGER NOT NULL CHECK (code_type IN (0, 1)),
|
||||
code_hash VARCHAR(512) NOT NULL,
|
||||
expires_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP + INTERVAL '10 minutes',
|
||||
used BOOLEAN DEFAULT FALSE,
|
||||
deleted BOOLEAN DEFAULT FALSE
|
||||
@@ -30,7 +42,7 @@ CREATE TABLE IF NOT EXISTS "confirmation_codes" (
|
||||
CREATE TABLE IF NOT EXISTS "sessions" (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
user_id BIGINT UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
guid VARCHAR(36) NOT NULL,
|
||||
guid UUID NOT NULL DEFAULT gen_random_uuid(),
|
||||
name VARCHAR(100),
|
||||
platform VARCHAR(32),
|
||||
latest_ip VARCHAR(16),
|
||||
@@ -43,6 +55,21 @@ CREATE TABLE IF NOT EXISTS "profiles" (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
user_id BIGINT UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
name VARCHAR(75) NOT NULL,
|
||||
bio VARCHAR(512),
|
||||
avatar_url VARCHAR(255),
|
||||
birthday TIMESTAMP
|
||||
birthday TIMESTAMP,
|
||||
color VARCHAR(7),
|
||||
color_grad VARCHAR(7)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "profile_settings" (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
profile_id BIGINT UNIQUE NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
|
||||
hide_fulfilled BOOLEAN DEFAULT TRUE,
|
||||
hide_profile_details BOOLEAN DEFAULT FALSE,
|
||||
hide_for_unauthenticated BOOLEAN DEFAULT FALSE,
|
||||
hide_birthday BOOLEAN DEFAULT FALSE,
|
||||
hide_dates BOOLEAN DEFAULT FALSE,
|
||||
captcha BOOLEAN DEFAULT FALSE,
|
||||
followers_only_interaction BOOLEAN DEFAULT FALSE
|
||||
)
|
||||
|
||||
Reference in New Issue
Block a user