From 8258ac0ad453ce171d80f2d148f54264687c5e35 Mon Sep 17 00:00:00 2001 From: Nikolai Papin Date: Mon, 16 Jun 2025 20:30:58 +0300 Subject: [PATCH] feat: all of sql for release 1 --- .gitignore | 2 + backend/internal/database/models.go | 49 +- backend/internal/database/query.sql.go | 816 ++++++++++++++++++++++++- sqlc/query.sql | 205 ++++++- sqlc/schema.sql | 45 +- 5 files changed, 1092 insertions(+), 25 deletions(-) diff --git a/.gitignore b/.gitignore index b5ff2ab..37292a1 100644 --- a/.gitignore +++ b/.gitignore @@ -158,3 +158,5 @@ tags *.env !example.env + +postgres_data diff --git a/backend/internal/database/models.go b/backend/internal/database/models.go index 2dae83f..609d5b3 100644 --- a/backend/internal/database/models.go +++ b/backend/internal/database/models.go @@ -8,39 +8,64 @@ import ( "github.com/jackc/pgx/v5/pgtype" ) +type BannedUser struct { + ID int64 + UserID int64 + Date pgtype.Timestamp + Reason pgtype.Text + ExpiresAt pgtype.Timestamp + BannedBy pgtype.Text + Pardoned pgtype.Bool + PardonedBy pgtype.Text +} + type ConfirmationCode struct { ID int64 UserID int64 - Type int32 - Code string + CodeType int32 + CodeHash string ExpiresAt pgtype.Timestamp Used pgtype.Bool Deleted pgtype.Bool } type LoginInformation struct { - ID int64 - UserID int64 - Email pgtype.Text - PasswordHash string - TotpEncrypted pgtype.Text - Email2faEnabled pgtype.Bool - PasswordChangeDate pgtype.Timestamp - PasswordTimesChanged pgtype.Int4 + ID int64 + UserID int64 + Email pgtype.Text + PasswordHash string + TotpEncrypted pgtype.Text + Email2faEnabled pgtype.Bool + PasswordChangeDate pgtype.Timestamp } type Profile struct { ID int64 UserID int64 Name string + Bio pgtype.Text AvatarUrl pgtype.Text Birthday pgtype.Timestamp + Color pgtype.Text + ColorGrad pgtype.Text +} + +type ProfileSetting struct { + ID int64 + ProfileID int64 + HideFulfilled pgtype.Bool + HideProfileDetails pgtype.Bool + HideForUnauthenticated pgtype.Bool + HideBirthday pgtype.Bool + HideDates pgtype.Bool + Captcha pgtype.Bool + FollowersOnlyInteraction pgtype.Bool } type Session struct { ID int64 UserID int64 - Guid string + Guid pgtype.UUID Name pgtype.Text Platform pgtype.Text LatestIp pgtype.Text @@ -53,6 +78,6 @@ type User struct { ID int64 Username string Verified pgtype.Bool - Banned pgtype.Bool RegistrationDate pgtype.Timestamp + Deleted pgtype.Bool } diff --git a/backend/internal/database/query.sql.go b/backend/internal/database/query.sql.go index 5d49fa7..dd92c37 100644 --- a/backend/internal/database/query.sql.go +++ b/backend/internal/database/query.sql.go @@ -7,12 +7,229 @@ package database import ( "context" + + "github.com/jackc/pgx/v5/pgtype" ) -const createUser = `-- name: CreateUser :one -INSERT INTO users(username, verified, banned, registration_date) VALUES ($1, false, false, NOW()) RETURNING id, username, verified, banned, registration_date +const createBannedUser = `-- name: CreateBannedUser :one + + +INSERT INTO banned_users(user_id, expires_at, reason, banned_by) +VALUES ( $1, $2, $3, $4) RETURNING id, user_id, date, reason, expires_at, banned_by, pardoned, pardoned_by ` +type CreateBannedUserParams struct { + UserID int64 + ExpiresAt pgtype.Timestamp + Reason pgtype.Text + BannedBy pgtype.Text +} + +// : }}} +// : Banned User Object {{{ +func (q *Queries) CreateBannedUser(ctx context.Context, arg CreateBannedUserParams) (BannedUser, error) { + row := q.db.QueryRow(ctx, createBannedUser, + arg.UserID, + arg.ExpiresAt, + arg.Reason, + arg.BannedBy, + ) + var i BannedUser + err := row.Scan( + &i.ID, + &i.UserID, + &i.Date, + &i.Reason, + &i.ExpiresAt, + &i.BannedBy, + &i.Pardoned, + &i.PardonedBy, + ) + return i, err +} + +const createConfirmationCode = `-- 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 id, user_id, code_type, code_hash, expires_at, used, deleted +` + +type CreateConfirmationCodeParams struct { + UserID int64 + CodeType int32 + Crypt string + ExpiresAt pgtype.Timestamp +} + +// : }}} +// : Confirmation Code Object {{{ +func (q *Queries) CreateConfirmationCode(ctx context.Context, arg CreateConfirmationCodeParams) (ConfirmationCode, error) { + row := q.db.QueryRow(ctx, createConfirmationCode, + arg.UserID, + arg.CodeType, + arg.Crypt, + arg.ExpiresAt, + ) + var i ConfirmationCode + err := row.Scan( + &i.ID, + &i.UserID, + &i.CodeType, + &i.CodeHash, + &i.ExpiresAt, + &i.Used, + &i.Deleted, + ) + return i, err +} + +const createLoginInformation = `-- name: CreateLoginInformation :one + + +INSERT INTO login_informations(user_id, email, password_hash) +VALUES ($1, $2, $3) RETURNING id, user_id, email, password_hash, totp_encrypted, email_2fa_enabled, password_change_date +` + +type CreateLoginInformationParams struct { + UserID int64 + Email pgtype.Text + PasswordHash string +} + +// : }}} +// : Login Information Object {{{ +func (q *Queries) CreateLoginInformation(ctx context.Context, arg CreateLoginInformationParams) (LoginInformation, error) { + row := q.db.QueryRow(ctx, createLoginInformation, arg.UserID, arg.Email, arg.PasswordHash) + var i LoginInformation + err := row.Scan( + &i.ID, + &i.UserID, + &i.Email, + &i.PasswordHash, + &i.TotpEncrypted, + &i.Email2faEnabled, + &i.PasswordChangeDate, + ) + return i, err +} + +const createProfile = `-- 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 id, user_id, name, bio, avatar_url, birthday, color, color_grad +` + +type CreateProfileParams struct { + UserID int64 + Name string + Bio pgtype.Text + Birthday pgtype.Timestamp + AvatarUrl pgtype.Text + Color pgtype.Text + ColorGrad pgtype.Text +} + +// }}} +// : Profile Object {{{ +func (q *Queries) CreateProfile(ctx context.Context, arg CreateProfileParams) (Profile, error) { + row := q.db.QueryRow(ctx, createProfile, + arg.UserID, + arg.Name, + arg.Bio, + arg.Birthday, + arg.AvatarUrl, + arg.Color, + arg.ColorGrad, + ) + var i Profile + err := row.Scan( + &i.ID, + &i.UserID, + &i.Name, + &i.Bio, + &i.AvatarUrl, + &i.Birthday, + &i.Color, + &i.ColorGrad, + ) + return i, err +} + +const createProfileSettings = `-- name: CreateProfileSettings :one + + +INSERT INTO profile_settings(profile_id) +VALUES ($1) RETURNING id, profile_id, hide_fulfilled, hide_profile_details, hide_for_unauthenticated, hide_birthday, hide_dates, captcha, followers_only_interaction +` + +// : }}} +// : Profile Settings Object {{{ +func (q *Queries) CreateProfileSettings(ctx context.Context, profileID int64) (ProfileSetting, error) { + row := q.db.QueryRow(ctx, createProfileSettings, profileID) + var i ProfileSetting + err := row.Scan( + &i.ID, + &i.ProfileID, + &i.HideFulfilled, + &i.HideProfileDetails, + &i.HideForUnauthenticated, + &i.HideBirthday, + &i.HideDates, + &i.Captcha, + &i.FollowersOnlyInteraction, + ) + return i, err +} + +const createSession = `-- name: CreateSession :one + + +INSERT INTO sessions(user_id, name, platform, latest_ip) +VALUES ($1, $2, $3, $4) RETURNING id, user_id, guid, name, platform, latest_ip, login_time, last_seen_date, terminated +` + +type CreateSessionParams struct { + UserID int64 + Name pgtype.Text + Platform pgtype.Text + LatestIp pgtype.Text +} + +// : }}} +// Session Object {{{ +func (q *Queries) CreateSession(ctx context.Context, arg CreateSessionParams) (Session, error) { + row := q.db.QueryRow(ctx, createSession, + arg.UserID, + arg.Name, + arg.Platform, + arg.LatestIp, + ) + var i Session + err := row.Scan( + &i.ID, + &i.UserID, + &i.Guid, + &i.Name, + &i.Platform, + &i.LatestIp, + &i.LoginTime, + &i.LastSeenDate, + &i.Terminated, + ) + return i, err +} + +const createUser = `-- name: CreateUser :one + + +INSERT INTO users(username, verified) +VALUES ($1, false) RETURNING id, username, verified, registration_date, deleted +` + +// vim:fileencoding=utf-8:foldmethod=marker +// : User Object {{{ func (q *Queries) CreateUser(ctx context.Context, username string) (User, error) { row := q.db.QueryRow(ctx, createUser, username) var i User @@ -20,8 +237,601 @@ func (q *Queries) CreateUser(ctx context.Context, username string) (User, error) &i.ID, &i.Username, &i.Verified, - &i.Banned, &i.RegistrationDate, + &i.Deleted, ) return i, err } + +const deleteUser = `-- name: DeleteUser :exec +DELETE FROM users +WHERE id = $1 +` + +func (q *Queries) DeleteUser(ctx context.Context, id int64) error { + _, err := q.db.Exec(ctx, deleteUser, id) + return err +} + +const deleteUserByUsername = `-- name: DeleteUserByUsername :exec +DELETE FROM users +WHERE username = $1 +` + +func (q *Queries) DeleteUserByUsername(ctx context.Context, username string) error { + _, err := q.db.Exec(ctx, deleteUserByUsername, username) + return err +} + +const getConfirmationCodeByCode = `-- name: GetConfirmationCodeByCode :one +SELECT id, user_id, code_type, code_hash, expires_at, used, deleted FROM confirmation_codes +WHERE user_id = $1 AND code_type = $2 AND expires_at > CURRENT_TIMESTAMP AND code_hash = crypt($3, code_hash) +` + +type GetConfirmationCodeByCodeParams struct { + UserID int64 + CodeType int32 + Crypt string +} + +func (q *Queries) GetConfirmationCodeByCode(ctx context.Context, arg GetConfirmationCodeByCodeParams) (ConfirmationCode, error) { + row := q.db.QueryRow(ctx, getConfirmationCodeByCode, arg.UserID, arg.CodeType, arg.Crypt) + var i ConfirmationCode + err := row.Scan( + &i.ID, + &i.UserID, + &i.CodeType, + &i.CodeHash, + &i.ExpiresAt, + &i.Used, + &i.Deleted, + ) + return i, err +} + +const getLoginInformationByUsername = `-- name: GetLoginInformationByUsername :one +SELECT login_informations.id, login_informations.user_id, login_informations.email, login_informations.password_hash, login_informations.totp_encrypted, login_informations.email_2fa_enabled, login_informations.password_change_date FROM login_informations +JOIN users ON users.id = login_informations.user_id +WHERE users.username = $1 +` + +func (q *Queries) GetLoginInformationByUsername(ctx context.Context, username string) (LoginInformation, error) { + row := q.db.QueryRow(ctx, getLoginInformationByUsername, username) + var i LoginInformation + err := row.Scan( + &i.ID, + &i.UserID, + &i.Email, + &i.PasswordHash, + &i.TotpEncrypted, + &i.Email2faEnabled, + &i.PasswordChangeDate, + ) + return i, err +} + +const getProfileByUsername = `-- name: GetProfileByUsername :one +SELECT profiles.id, profiles.user_id, profiles.name, profiles.bio, profiles.avatar_url, profiles.birthday, profiles.color, profiles.color_grad FROM profiles +JOIN users ON users.id = profiles.user_id +WHERE users.username = $1 +` + +func (q *Queries) GetProfileByUsername(ctx context.Context, username string) (Profile, error) { + row := q.db.QueryRow(ctx, getProfileByUsername, username) + var i Profile + err := row.Scan( + &i.ID, + &i.UserID, + &i.Name, + &i.Bio, + &i.AvatarUrl, + &i.Birthday, + &i.Color, + &i.ColorGrad, + ) + return i, err +} + +const getProfileByUsernameRestricted = `-- 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) +` + +type GetProfileByUsernameRestrictedParams struct { + Username string + Column2 pgtype.Bool +} + +type GetProfileByUsernameRestrictedRow struct { + Username string + Name string + Birthday pgtype.Timestamp + Bio pgtype.Text + AvatarUrl pgtype.Text + Color pgtype.Text + ColorGrad pgtype.Text + HideProfileDetails pgtype.Bool +} + +func (q *Queries) GetProfileByUsernameRestricted(ctx context.Context, arg GetProfileByUsernameRestrictedParams) (GetProfileByUsernameRestrictedRow, error) { + row := q.db.QueryRow(ctx, getProfileByUsernameRestricted, arg.Username, arg.Column2) + var i GetProfileByUsernameRestrictedRow + err := row.Scan( + &i.Username, + &i.Name, + &i.Birthday, + &i.Bio, + &i.AvatarUrl, + &i.Color, + &i.ColorGrad, + &i.HideProfileDetails, + ) + return i, err +} + +const getProfileSettingsByUsername = `-- name: GetProfileSettingsByUsername :one +SELECT profile_settings.id, profile_settings.profile_id, profile_settings.hide_fulfilled, profile_settings.hide_profile_details, profile_settings.hide_for_unauthenticated, profile_settings.hide_birthday, profile_settings.hide_dates, profile_settings.captcha, profile_settings.followers_only_interaction FROM profile_settings +JOIN profiles ON profiles.id = profile_settings.profile_id +JOIN users ON users.id = profiles.user_id +WHERE users.username = $1 +` + +func (q *Queries) GetProfileSettingsByUsername(ctx context.Context, username string) (ProfileSetting, error) { + row := q.db.QueryRow(ctx, getProfileSettingsByUsername, username) + var i ProfileSetting + err := row.Scan( + &i.ID, + &i.ProfileID, + &i.HideFulfilled, + &i.HideProfileDetails, + &i.HideForUnauthenticated, + &i.HideBirthday, + &i.HideDates, + &i.Captcha, + &i.FollowersOnlyInteraction, + ) + return i, err +} + +const getProfilesRestricted = `-- 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 +` + +type GetProfilesRestrictedParams struct { + Column1 pgtype.Int4 + Column2 pgtype.Bool +} + +type GetProfilesRestrictedRow struct { + Username string + Name string + AvatarUrl pgtype.Text + Color pgtype.Text + ColorGrad pgtype.Text + HideProfileDetails pgtype.Bool +} + +func (q *Queries) GetProfilesRestricted(ctx context.Context, arg GetProfilesRestrictedParams) ([]GetProfilesRestrictedRow, error) { + rows, err := q.db.Query(ctx, getProfilesRestricted, arg.Column1, arg.Column2) + if err != nil { + return nil, err + } + defer rows.Close() + var items []GetProfilesRestrictedRow + for rows.Next() { + var i GetProfilesRestrictedRow + if err := rows.Scan( + &i.Username, + &i.Name, + &i.AvatarUrl, + &i.Color, + &i.ColorGrad, + &i.HideProfileDetails, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + +const getUser = `-- name: GetUser :one +SELECT id, username, verified, registration_date, deleted FROM users +WHERE id = $1 +` + +func (q *Queries) GetUser(ctx context.Context, id int64) (User, error) { + row := q.db.QueryRow(ctx, getUser, id) + var i User + err := row.Scan( + &i.ID, + &i.Username, + &i.Verified, + &i.RegistrationDate, + &i.Deleted, + ) + return i, err +} + +const getUserBans = `-- name: GetUserBans :many +SELECT id, user_id, date, reason, expires_at, banned_by, pardoned, pardoned_by FROM banned_users +WHERE user_id = $1 +` + +func (q *Queries) GetUserBans(ctx context.Context, userID int64) ([]BannedUser, error) { + rows, err := q.db.Query(ctx, getUserBans, userID) + if err != nil { + return nil, err + } + defer rows.Close() + var items []BannedUser + for rows.Next() { + var i BannedUser + if err := rows.Scan( + &i.ID, + &i.UserID, + &i.Date, + &i.Reason, + &i.ExpiresAt, + &i.BannedBy, + &i.Pardoned, + &i.PardonedBy, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + +const getUserBansByUsername = `-- name: GetUserBansByUsername :many +SELECT banned_users.id, banned_users.user_id, banned_users.date, banned_users.reason, banned_users.expires_at, banned_users.banned_by, banned_users.pardoned, banned_users.pardoned_by FROM banned_users +JOIN users ON users.id = banned_users.user_id +WHERE users.username = $1 +` + +func (q *Queries) GetUserBansByUsername(ctx context.Context, username string) ([]BannedUser, error) { + rows, err := q.db.Query(ctx, getUserBansByUsername, username) + if err != nil { + return nil, err + } + defer rows.Close() + var items []BannedUser + for rows.Next() { + var i BannedUser + if err := rows.Scan( + &i.ID, + &i.UserID, + &i.Date, + &i.Reason, + &i.ExpiresAt, + &i.BannedBy, + &i.Pardoned, + &i.PardonedBy, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + +const getUserByUsername = `-- name: GetUserByUsername :one +SELECT id, username, verified, registration_date, deleted FROM users +WHERE username = $1 +` + +func (q *Queries) GetUserByUsername(ctx context.Context, username string) (User, error) { + row := q.db.QueryRow(ctx, getUserByUsername, username) + var i User + err := row.Scan( + &i.ID, + &i.Username, + &i.Verified, + &i.RegistrationDate, + &i.Deleted, + ) + return i, err +} + +const getUserSessions = `-- name: GetUserSessions :many +SELECT id, user_id, guid, name, platform, latest_ip, login_time, last_seen_date, terminated FROM sessions +WHERE user_id = $1 AND terminated IS FALSE +` + +func (q *Queries) GetUserSessions(ctx context.Context, userID int64) ([]Session, error) { + rows, err := q.db.Query(ctx, getUserSessions, userID) + if err != nil { + return nil, err + } + defer rows.Close() + var items []Session + for rows.Next() { + var i Session + if err := rows.Scan( + &i.ID, + &i.UserID, + &i.Guid, + &i.Name, + &i.Platform, + &i.LatestIp, + &i.LoginTime, + &i.LastSeenDate, + &i.Terminated, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + +const pruneExpiredConfirmationCodes = `-- name: PruneExpiredConfirmationCodes :exec +DELETE FROM confirmation_codes +WHERE expires_at < CURRENT_TIMESTAMP +` + +func (q *Queries) PruneExpiredConfirmationCodes(ctx context.Context) error { + _, err := q.db.Exec(ctx, pruneExpiredConfirmationCodes) + return err +} + +const pruneTerminatedSessions = `-- name: PruneTerminatedSessions :exec +DELETE FROM sessions +WHERE terminated IS TRUE +` + +func (q *Queries) PruneTerminatedSessions(ctx context.Context) error { + _, err := q.db.Exec(ctx, pruneTerminatedSessions) + return err +} + +const updateBannedUser = `-- name: UpdateBannedUser :exec +UPDATE banned_users +SET reason = $2, expires_at = $3, banned_by = $4, pardoned = $5, pardoned_by = $6 +WHERE id = $1 +` + +type UpdateBannedUserParams struct { + ID int64 + Reason pgtype.Text + ExpiresAt pgtype.Timestamp + BannedBy pgtype.Text + Pardoned pgtype.Bool + PardonedBy pgtype.Text +} + +func (q *Queries) UpdateBannedUser(ctx context.Context, arg UpdateBannedUserParams) error { + _, err := q.db.Exec(ctx, updateBannedUser, + arg.ID, + arg.Reason, + arg.ExpiresAt, + arg.BannedBy, + arg.Pardoned, + arg.PardonedBy, + ) + return err +} + +const updateConfirmationCode = `-- name: UpdateConfirmationCode :exec +UPDATE confirmation_codes +SET used = $2, deleted = $3 +WHERE id = $1 +` + +type UpdateConfirmationCodeParams struct { + ID int64 + Used pgtype.Bool + Deleted pgtype.Bool +} + +func (q *Queries) UpdateConfirmationCode(ctx context.Context, arg UpdateConfirmationCodeParams) error { + _, err := q.db.Exec(ctx, updateConfirmationCode, arg.ID, arg.Used, arg.Deleted) + return err +} + +const updateLoginInformationByUsername = `-- 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 +` + +type UpdateLoginInformationByUsernameParams struct { + Username string + Email pgtype.Text + PasswordHash string + TotpEncrypted pgtype.Text + Email2faEnabled pgtype.Bool + PasswordChangeDate pgtype.Timestamp +} + +func (q *Queries) UpdateLoginInformationByUsername(ctx context.Context, arg UpdateLoginInformationByUsernameParams) error { + _, err := q.db.Exec(ctx, updateLoginInformationByUsername, + arg.Username, + arg.Email, + arg.PasswordHash, + arg.TotpEncrypted, + arg.Email2faEnabled, + arg.PasswordChangeDate, + ) + return err +} + +const updateProfileByUsername = `-- 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 +` + +type UpdateProfileByUsernameParams struct { + Username string + Name string + Bio pgtype.Text + Birthday pgtype.Timestamp + AvatarUrl pgtype.Text + Color pgtype.Text + ColorGrad pgtype.Text +} + +func (q *Queries) UpdateProfileByUsername(ctx context.Context, arg UpdateProfileByUsernameParams) error { + _, err := q.db.Exec(ctx, updateProfileByUsername, + arg.Username, + arg.Name, + arg.Bio, + arg.Birthday, + arg.AvatarUrl, + arg.Color, + arg.ColorGrad, + ) + return err +} + +const updateProfileSettings = `-- 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 +` + +type UpdateProfileSettingsParams struct { + ID int64 + HideFulfilled pgtype.Bool + HideProfileDetails pgtype.Bool + HideForUnauthenticated pgtype.Bool + HideBirthday pgtype.Bool + HideDates pgtype.Bool + Captcha pgtype.Bool + FollowersOnlyInteraction pgtype.Bool +} + +func (q *Queries) UpdateProfileSettings(ctx context.Context, arg UpdateProfileSettingsParams) error { + _, err := q.db.Exec(ctx, updateProfileSettings, + arg.ID, + arg.HideFulfilled, + arg.HideProfileDetails, + arg.HideForUnauthenticated, + arg.HideBirthday, + arg.HideDates, + arg.Captcha, + arg.FollowersOnlyInteraction, + ) + return err +} + +const updateSession = `-- 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 +` + +type UpdateSessionParams struct { + ID int64 + Name pgtype.Text + Platform pgtype.Text + LatestIp pgtype.Text + LoginTime pgtype.Timestamp + LastSeenDate pgtype.Timestamp + Terminated pgtype.Bool +} + +func (q *Queries) UpdateSession(ctx context.Context, arg UpdateSessionParams) error { + _, err := q.db.Exec(ctx, updateSession, + arg.ID, + arg.Name, + arg.Platform, + arg.LatestIp, + arg.LoginTime, + arg.LastSeenDate, + arg.Terminated, + ) + return err +} + +const updateUser = `-- name: UpdateUser :exec +UPDATE users +SET verified = $2, deleted = $3 +WHERE id = $1 +` + +type UpdateUserParams struct { + ID int64 + Verified pgtype.Bool + Deleted pgtype.Bool +} + +func (q *Queries) UpdateUser(ctx context.Context, arg UpdateUserParams) error { + _, err := q.db.Exec(ctx, updateUser, arg.ID, arg.Verified, arg.Deleted) + return err +} + +const updateUserByUsername = `-- name: UpdateUserByUsername :exec +UPDATE users +SET verified = $2, deleted = $3 +WHERE username = $1 +` + +type UpdateUserByUsernameParams struct { + Username string + Verified pgtype.Bool + Deleted pgtype.Bool +} + +func (q *Queries) UpdateUserByUsername(ctx context.Context, arg UpdateUserByUsernameParams) error { + _, err := q.db.Exec(ctx, updateUserByUsername, arg.Username, arg.Verified, arg.Deleted) + return err +} diff --git a/sqlc/query.sql b/sqlc/query.sql index afbc82e..d7f4b35 100644 --- a/sqlc/query.sql +++ b/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; + +--: }}} diff --git a/sqlc/schema.sql b/sqlc/schema.sql index cadddcc..55ed0de 100644 --- a/sqlc/schema.sql +++ b/sqlc/schema.sql @@ -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 +)