feat: auth service logic for purging expired unverified accounts upon registration, new sql queries for this purpose
This commit is contained in:
@@ -11,6 +11,48 @@ import (
|
|||||||
"github.com/jackc/pgx/v5/pgtype"
|
"github.com/jackc/pgx/v5/pgtype"
|
||||||
)
|
)
|
||||||
|
|
||||||
|
const checkUserRegistrationAvailability = `-- name: CheckUserRegistrationAvailability :one
|
||||||
|
SELECT
|
||||||
|
COUNT(CASE WHEN users.username = $1::text THEN 1 END) > 0 AS username_busy,
|
||||||
|
COUNT(CASE WHEN linfo.email = $2::text THEN 1 END) > 0 AS email_busy
|
||||||
|
FROM users
|
||||||
|
JOIN login_informations AS linfo ON linfo.user_id = users.id
|
||||||
|
WHERE
|
||||||
|
(
|
||||||
|
users.username = $1::text OR
|
||||||
|
linfo.email = $2::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
|
||||||
|
)
|
||||||
|
)
|
||||||
|
`
|
||||||
|
|
||||||
|
type CheckUserRegistrationAvailabilityParams struct {
|
||||||
|
Username string
|
||||||
|
Email string
|
||||||
|
}
|
||||||
|
|
||||||
|
type CheckUserRegistrationAvailabilityRow struct {
|
||||||
|
UsernameBusy bool
|
||||||
|
EmailBusy bool
|
||||||
|
}
|
||||||
|
|
||||||
|
func (q *Queries) CheckUserRegistrationAvailability(ctx context.Context, arg CheckUserRegistrationAvailabilityParams) (CheckUserRegistrationAvailabilityRow, error) {
|
||||||
|
row := q.db.QueryRow(ctx, checkUserRegistrationAvailability, arg.Username, arg.Email)
|
||||||
|
var i CheckUserRegistrationAvailabilityRow
|
||||||
|
err := row.Scan(&i.UsernameBusy, &i.EmailBusy)
|
||||||
|
return i, err
|
||||||
|
}
|
||||||
|
|
||||||
const createBannedUser = `-- name: CreateBannedUser :one
|
const createBannedUser = `-- name: CreateBannedUser :one
|
||||||
INSERT INTO banned_users(user_id, expires_at, reason, banned_by)
|
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
|
VALUES ( $1, $2, $3, $4) RETURNING id, user_id, date, reason, expires_at, banned_by, pardoned, pardoned_by
|
||||||
@@ -209,6 +251,35 @@ func (q *Queries) CreateUser(ctx context.Context, username string) (User, error)
|
|||||||
return i, err
|
return i, err
|
||||||
}
|
}
|
||||||
|
|
||||||
|
const deleteUnverifiedAccountsHavingUsernameOrEmail = `-- name: DeleteUnverifiedAccountsHavingUsernameOrEmail :one
|
||||||
|
WITH deleted_rows AS (
|
||||||
|
DELETE FROM users
|
||||||
|
WHERE
|
||||||
|
(username = $1::text OR
|
||||||
|
EXISTS (
|
||||||
|
SELECT 1
|
||||||
|
FROM login_informations AS linfo
|
||||||
|
WHERE linfo.user_id = users.id
|
||||||
|
AND linfo.email = $2::text
|
||||||
|
))
|
||||||
|
AND verified IS FALSE
|
||||||
|
RETURNING id, username, verified, registration_date, deleted
|
||||||
|
)
|
||||||
|
SELECT COUNT(*) AS deleted_count FROM deleted_rows
|
||||||
|
`
|
||||||
|
|
||||||
|
type DeleteUnverifiedAccountsHavingUsernameOrEmailParams struct {
|
||||||
|
Username string
|
||||||
|
Email string
|
||||||
|
}
|
||||||
|
|
||||||
|
func (q *Queries) DeleteUnverifiedAccountsHavingUsernameOrEmail(ctx context.Context, arg DeleteUnverifiedAccountsHavingUsernameOrEmailParams) (int64, error) {
|
||||||
|
row := q.db.QueryRow(ctx, deleteUnverifiedAccountsHavingUsernameOrEmail, arg.Username, arg.Email)
|
||||||
|
var deleted_count int64
|
||||||
|
err := row.Scan(&deleted_count)
|
||||||
|
return deleted_count, err
|
||||||
|
}
|
||||||
|
|
||||||
const deleteUser = `-- name: DeleteUser :exec
|
const deleteUser = `-- name: DeleteUser :exec
|
||||||
DELETE FROM users
|
DELETE FROM users
|
||||||
WHERE id = $1
|
WHERE id = $1
|
||||||
@@ -603,6 +674,69 @@ func (q *Queries) GetValidConfirmationCodeByCode(ctx context.Context, arg GetVal
|
|||||||
return i, err
|
return i, err
|
||||||
}
|
}
|
||||||
|
|
||||||
|
const getValidConfirmationCodesByUsername = `-- name: GetValidConfirmationCodesByUsername :many
|
||||||
|
SELECT confirmation_codes.id, user_id, code_type, code_hash, expires_at, used, confirmation_codes.deleted, users.id, username, verified, registration_date, users.deleted FROM confirmation_codes
|
||||||
|
JOIN users on users.id = confirmation_codes.user_id
|
||||||
|
WHERE
|
||||||
|
users.username = $1::text AND
|
||||||
|
code_type = $2::integer AND
|
||||||
|
expires_at > CURRENT_TIMESTAMP AND
|
||||||
|
used IS FALSE
|
||||||
|
`
|
||||||
|
|
||||||
|
type GetValidConfirmationCodesByUsernameParams struct {
|
||||||
|
Username string
|
||||||
|
CodeType int32
|
||||||
|
}
|
||||||
|
|
||||||
|
type GetValidConfirmationCodesByUsernameRow struct {
|
||||||
|
ID int64
|
||||||
|
UserID int64
|
||||||
|
CodeType int32
|
||||||
|
CodeHash string
|
||||||
|
ExpiresAt pgtype.Timestamp
|
||||||
|
Used *bool
|
||||||
|
Deleted *bool
|
||||||
|
ID_2 int64
|
||||||
|
Username string
|
||||||
|
Verified *bool
|
||||||
|
RegistrationDate pgtype.Timestamp
|
||||||
|
Deleted_2 *bool
|
||||||
|
}
|
||||||
|
|
||||||
|
func (q *Queries) GetValidConfirmationCodesByUsername(ctx context.Context, arg GetValidConfirmationCodesByUsernameParams) ([]GetValidConfirmationCodesByUsernameRow, error) {
|
||||||
|
rows, err := q.db.Query(ctx, getValidConfirmationCodesByUsername, arg.Username, arg.CodeType)
|
||||||
|
if err != nil {
|
||||||
|
return nil, err
|
||||||
|
}
|
||||||
|
defer rows.Close()
|
||||||
|
var items []GetValidConfirmationCodesByUsernameRow
|
||||||
|
for rows.Next() {
|
||||||
|
var i GetValidConfirmationCodesByUsernameRow
|
||||||
|
if err := rows.Scan(
|
||||||
|
&i.ID,
|
||||||
|
&i.UserID,
|
||||||
|
&i.CodeType,
|
||||||
|
&i.CodeHash,
|
||||||
|
&i.ExpiresAt,
|
||||||
|
&i.Used,
|
||||||
|
&i.Deleted,
|
||||||
|
&i.ID_2,
|
||||||
|
&i.Username,
|
||||||
|
&i.Verified,
|
||||||
|
&i.RegistrationDate,
|
||||||
|
&i.Deleted_2,
|
||||||
|
); err != nil {
|
||||||
|
return nil, err
|
||||||
|
}
|
||||||
|
items = append(items, i)
|
||||||
|
}
|
||||||
|
if err := rows.Err(); err != nil {
|
||||||
|
return nil, err
|
||||||
|
}
|
||||||
|
return items, nil
|
||||||
|
}
|
||||||
|
|
||||||
const getValidUserByLoginCredentials = `-- name: GetValidUserByLoginCredentials :one
|
const getValidUserByLoginCredentials = `-- name: GetValidUserByLoginCredentials :one
|
||||||
SELECT
|
SELECT
|
||||||
users.id,
|
users.id,
|
||||||
|
|||||||
@@ -58,30 +58,58 @@ func NewAuthService(_log *zap.Logger, _dbctx database.DbContext, _redis *redis.C
|
|||||||
|
|
||||||
func (a *authServiceImpl) RegistrationBegin(request models.RegistrationBeginRequest) (bool, error) {
|
func (a *authServiceImpl) RegistrationBegin(request models.RegistrationBeginRequest) (bool, error) {
|
||||||
|
|
||||||
|
var occupationStatus database.CheckUserRegistrationAvailabilityRow
|
||||||
var user database.User
|
var user database.User
|
||||||
var generatedCode string
|
var generatedCode string
|
||||||
var generatedCodeHash string
|
var generatedCodeHash string
|
||||||
var passwordHash string
|
var passwordHash string
|
||||||
|
var err error
|
||||||
|
|
||||||
helper, db, _ := database.NewDbHelperTransaction(a.dbctx)
|
helper, db, _ := database.NewDbHelperTransaction(a.dbctx)
|
||||||
defer helper.Rollback()
|
defer helper.Rollback()
|
||||||
|
|
||||||
var err error
|
if occupationStatus, err = db.TXQueries.CheckUserRegistrationAvailability(db.CTX, database.CheckUserRegistrationAvailabilityParams{
|
||||||
|
Email: request.Email,
|
||||||
|
Username: request.Username,
|
||||||
|
}); err != nil {
|
||||||
|
a.log.Error(
|
||||||
|
"Failed to check credentials availability for registration",
|
||||||
|
zap.String("username", request.Username),
|
||||||
|
zap.String("email", request.Email),
|
||||||
|
zap.Error(err))
|
||||||
|
return false, errs.ErrServerError
|
||||||
|
}
|
||||||
|
|
||||||
// TODO: get user if it exists. If not verified and no valid code exists, delete
|
if occupationStatus.UsernameBusy {
|
||||||
// and recreate
|
a.log.Warn(
|
||||||
|
"Attempted registration for a taken username",
|
||||||
|
zap.String("email", request.Email),
|
||||||
|
zap.String("username", request.Username))
|
||||||
|
return false, errs.ErrUsernameTaken
|
||||||
|
|
||||||
|
} else if occupationStatus.EmailBusy {
|
||||||
|
// Falsely confirm in order to avoid disclosing registered email addresses
|
||||||
|
a.log.Warn(
|
||||||
|
"Attempted registration for a taken email",
|
||||||
|
zap.String("email", request.Email),
|
||||||
|
zap.String("username", request.Username))
|
||||||
|
return true, nil
|
||||||
|
|
||||||
|
} else {
|
||||||
|
if _, err := db.TXQueries.DeleteUnverifiedAccountsHavingUsernameOrEmail(db.CTX, database.DeleteUnverifiedAccountsHavingUsernameOrEmailParams{
|
||||||
|
Username: request.Username,
|
||||||
|
Email: request.Email,
|
||||||
|
}); err != nil {
|
||||||
|
a.log.Error(
|
||||||
|
"Failed to purge unverified accounts as part of registration",
|
||||||
|
zap.String("email", request.Email),
|
||||||
|
zap.String("username", request.Username),
|
||||||
|
zap.Error(err))
|
||||||
|
return false, errs.ErrServerError
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
if user, err = db.TXQueries.CreateUser(db.CTX, request.Username); err != nil {
|
if user, err = db.TXQueries.CreateUser(db.CTX, request.Username); err != nil {
|
||||||
|
|
||||||
if errs.MatchPgError(err, pgerrcode.UniqueViolation) {
|
|
||||||
a.log.Warn(
|
|
||||||
"Attempted registration for a taken username",
|
|
||||||
zap.String("username", request.Username),
|
|
||||||
zap.Error(err))
|
|
||||||
|
|
||||||
return false, errs.ErrUsernameTaken
|
|
||||||
}
|
|
||||||
|
|
||||||
a.log.Error("Failed to add user to database", zap.Error(err))
|
a.log.Error("Failed to add user to database", zap.Error(err))
|
||||||
return false, errs.ErrServerError
|
return false, errs.ErrServerError
|
||||||
}
|
}
|
||||||
|
|||||||
@@ -56,6 +56,29 @@ SELECT users.* FROM users
|
|||||||
JOIN login_informations linfo ON linfo.user_id = users.id
|
JOIN login_informations linfo ON linfo.user_id = users.id
|
||||||
WHERE linfo.email = @email::text;
|
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
|
;-- name: GetValidUserByLoginCredentials :one
|
||||||
SELECT
|
SELECT
|
||||||
users.id,
|
users.id,
|
||||||
@@ -72,6 +95,46 @@ WHERE
|
|||||||
banned.user_id IS NULL AND -- Not banned
|
banned.user_id IS NULL AND -- Not banned
|
||||||
linfo.password_hash = crypt(@password::text, linfo.password_hash); -- Password hash matches
|
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 {{{
|
--: Banned User Object {{{
|
||||||
@@ -146,6 +209,15 @@ WHERE
|
|||||||
used IS FALSE AND
|
used IS FALSE AND
|
||||||
code_hash = crypt(@code::text, code_hash);
|
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
|
;-- name: UpdateConfirmationCode :exec
|
||||||
UPDATE confirmation_codes
|
UPDATE confirmation_codes
|
||||||
SET
|
SET
|
||||||
|
|||||||
Reference in New Issue
Block a user