refactor: began refactoring access control in sql
This commit is contained in:
@@ -11,6 +11,52 @@ import (
|
||||
"github.com/jackc/pgx/v5/pgtype"
|
||||
)
|
||||
|
||||
const checkProfileAccess = `-- name: CheckProfileAccess :one
|
||||
SELECT
|
||||
CASE WHEN u.deleted OR NOT u.verified THEN TRUE ELSE FALSE END AS user_unavailable,
|
||||
CASE WHEN EXISTS (
|
||||
SELECT 1
|
||||
FROM banned_users
|
||||
WHERE user_id = u.id AND
|
||||
pardoned IS FALSE AND
|
||||
(expires_at IS NULL OR expires_at < CURRENT_TIMESTAMP)
|
||||
) THEN TRUE ELSE FALSE END AS user_banned,
|
||||
CASE WHEN ps.hide_profile_details THEN TRUE ELSE FALSE END AS hidden,
|
||||
CASE WHEN ps.hide_for_unauthenticated AND $2::text = '' THEN TRUE ELSE FALSE END AS auth_required,
|
||||
CASE WHEN ps.captcha THEN TRUE ELSE FALSE END AS captcha_required
|
||||
FROM profiles p
|
||||
JOIN profile_settings ps ON ps.profile_id = p.id
|
||||
JOIN users u ON p.user_id = u.id
|
||||
WHERE p.id = $1
|
||||
`
|
||||
|
||||
type CheckProfileAccessParams struct {
|
||||
ID int64
|
||||
Requester string
|
||||
}
|
||||
|
||||
type CheckProfileAccessRow struct {
|
||||
UserUnavailable bool
|
||||
UserBanned bool
|
||||
Hidden bool
|
||||
AuthRequired bool
|
||||
CaptchaRequired bool
|
||||
}
|
||||
|
||||
// XXX: recheck, was tired
|
||||
func (q *Queries) CheckProfileAccess(ctx context.Context, arg CheckProfileAccessParams) (CheckProfileAccessRow, error) {
|
||||
row := q.db.QueryRow(ctx, checkProfileAccess, arg.ID, arg.Requester)
|
||||
var i CheckProfileAccessRow
|
||||
err := row.Scan(
|
||||
&i.UserUnavailable,
|
||||
&i.UserBanned,
|
||||
&i.Hidden,
|
||||
&i.AuthRequired,
|
||||
&i.CaptchaRequired,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
||||
const checkUserRegistrationAvailability = `-- name: CheckUserRegistrationAvailability :one
|
||||
SELECT
|
||||
COUNT(CASE WHEN users.username = $1::text THEN 1 END) > 0 AS username_busy,
|
||||
@@ -253,6 +299,60 @@ func (q *Queries) CreateUser(ctx context.Context, username string) (User, error)
|
||||
return i, err
|
||||
}
|
||||
|
||||
const createWish = `-- name: CreateWish :one
|
||||
INSERT INTO wishes(
|
||||
wish_list_id,
|
||||
wish_list_guid,
|
||||
name,
|
||||
description,
|
||||
picture_url,
|
||||
stars)
|
||||
VALUES
|
||||
(
|
||||
(SELECT id FROM wish_lists wl WHERE wl.guid = ($1::text)::uuid),
|
||||
($1::text)::uuid,
|
||||
$2::text,
|
||||
$3::text,
|
||||
$4::text,
|
||||
$5::smallint
|
||||
)
|
||||
RETURNING id, guid, wish_list_id, wish_list_guid, name, description, picture_url, stars, creation_date, fulfilled, fulfilled_date, deleted
|
||||
`
|
||||
|
||||
type CreateWishParams struct {
|
||||
WishListGuid string
|
||||
Name string
|
||||
Description string
|
||||
PictureUrl string
|
||||
Stars int16
|
||||
}
|
||||
|
||||
func (q *Queries) CreateWish(ctx context.Context, arg CreateWishParams) (Wish, error) {
|
||||
row := q.db.QueryRow(ctx, createWish,
|
||||
arg.WishListGuid,
|
||||
arg.Name,
|
||||
arg.Description,
|
||||
arg.PictureUrl,
|
||||
arg.Stars,
|
||||
)
|
||||
var i Wish
|
||||
err := row.Scan(
|
||||
&i.ID,
|
||||
&i.Guid,
|
||||
&i.WishListID,
|
||||
&i.WishListGuid,
|
||||
&i.Name,
|
||||
&i.Description,
|
||||
&i.PictureUrl,
|
||||
&i.Stars,
|
||||
&i.CreationDate,
|
||||
&i.Fulfilled,
|
||||
&i.FulfilledDate,
|
||||
&i.Deleted,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
||||
const createWishList = `-- name: CreateWishList :one
|
||||
INSERT INTO wish_lists(profile_id, hidden, name, icon_name, color, color_grad)
|
||||
VALUES (
|
||||
@@ -401,34 +501,15 @@ SELECT
|
||||
p.avatar_url,
|
||||
CASE WHEN ps.hide_birthday THEN NULL ELSE p.birthday END AS birthday,
|
||||
p.color,
|
||||
p.color_grad,
|
||||
NOT ($1::text = '' AND ps.hide_for_unauthenticated) AS access_allowed
|
||||
p.color_grad
|
||||
FROM
|
||||
users AS u
|
||||
JOIN profiles AS p ON u.id = p.user_id
|
||||
JOIN profile_settings AS ps ON p.id = ps.profile_id
|
||||
WHERE
|
||||
u.username = $2::text
|
||||
AND (
|
||||
$2::text = $1::text
|
||||
OR
|
||||
u.deleted IS FALSE
|
||||
AND u.verified IS TRUE
|
||||
AND NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM banned_users
|
||||
WHERE user_id = u.id AND
|
||||
pardoned IS FALSE AND
|
||||
(expires_at IS NULL OR expires_at < CURRENT_TIMESTAMP)
|
||||
)
|
||||
)
|
||||
u.username = $1::text
|
||||
`
|
||||
|
||||
type GetProfileByUsernameWithPrivacyParams struct {
|
||||
Requester string
|
||||
SearchedUsername string
|
||||
}
|
||||
|
||||
type GetProfileByUsernameWithPrivacyRow struct {
|
||||
Username string
|
||||
Name string
|
||||
@@ -437,11 +518,11 @@ type GetProfileByUsernameWithPrivacyRow struct {
|
||||
Birthday pgtype.Timestamp
|
||||
Color string
|
||||
ColorGrad string
|
||||
AccessAllowed *bool
|
||||
}
|
||||
|
||||
func (q *Queries) GetProfileByUsernameWithPrivacy(ctx context.Context, arg GetProfileByUsernameWithPrivacyParams) (GetProfileByUsernameWithPrivacyRow, error) {
|
||||
row := q.db.QueryRow(ctx, getProfileByUsernameWithPrivacy, arg.Requester, arg.SearchedUsername)
|
||||
// FIXME: tweak backend code to handle privacy correctly
|
||||
func (q *Queries) GetProfileByUsernameWithPrivacy(ctx context.Context, searchedUsername string) (GetProfileByUsernameWithPrivacyRow, error) {
|
||||
row := q.db.QueryRow(ctx, getProfileByUsernameWithPrivacy, searchedUsername)
|
||||
var i GetProfileByUsernameWithPrivacyRow
|
||||
err := row.Scan(
|
||||
&i.Username,
|
||||
@@ -451,7 +532,6 @@ func (q *Queries) GetProfileByUsernameWithPrivacy(ctx context.Context, arg GetPr
|
||||
&i.Birthday,
|
||||
&i.Color,
|
||||
&i.ColorGrad,
|
||||
&i.AccessAllowed,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
@@ -911,6 +991,102 @@ func (q *Queries) GetValidUserSessions(ctx context.Context, userID int64) ([]Ses
|
||||
return items, nil
|
||||
}
|
||||
|
||||
const getWishByGuid = `-- name: GetWishByGuid :one
|
||||
SELECT id, guid, wish_list_id, wish_list_guid, name, description, picture_url, stars, creation_date, fulfilled, fulfilled_date, deleted FROM wishes w
|
||||
WHERE w.guid = ($1::text)::uuid
|
||||
`
|
||||
|
||||
func (q *Queries) GetWishByGuid(ctx context.Context, guid string) (Wish, error) {
|
||||
row := q.db.QueryRow(ctx, getWishByGuid, guid)
|
||||
var i Wish
|
||||
err := row.Scan(
|
||||
&i.ID,
|
||||
&i.Guid,
|
||||
&i.WishListID,
|
||||
&i.WishListGuid,
|
||||
&i.Name,
|
||||
&i.Description,
|
||||
&i.PictureUrl,
|
||||
&i.Stars,
|
||||
&i.CreationDate,
|
||||
&i.Fulfilled,
|
||||
&i.FulfilledDate,
|
||||
&i.Deleted,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
||||
const getWishByGuidWithPrivacy = `-- name: GetWishByGuidWithPrivacy :one
|
||||
SELECT
|
||||
w.id, w.guid, w.wish_list_id, w.wish_list_guid, w.name, w.description, w.picture_url, w.stars, w.creation_date, w.fulfilled, w.fulfilled_date, w.deleted,
|
||||
CASE
|
||||
WHEN
|
||||
(
|
||||
$1::text = u.username OR
|
||||
NOT ps.hide_profile_details AND
|
||||
NOT
|
||||
(
|
||||
ps.hide_for_unauthenticated AND
|
||||
$1::text = ''
|
||||
) AND
|
||||
NOT wl.hidden
|
||||
)
|
||||
THEN TRUE
|
||||
ELSE FALSE
|
||||
END AS access_allowed
|
||||
FROM wishes w
|
||||
JOIN wish_lists wl ON w.wish_list_id = wl.id
|
||||
JOIN profiles p ON wl.profile_id = p.id
|
||||
JOIN profile_settings ps ON ps.profile_id = p.id
|
||||
JOIN users u ON p.user_id = u.id
|
||||
WHERE
|
||||
w.guid = ($2::text)::uuid AND
|
||||
w.deleted IS FALSE
|
||||
`
|
||||
|
||||
type GetWishByGuidWithPrivacyParams struct {
|
||||
Requester string
|
||||
Guid string
|
||||
}
|
||||
|
||||
type GetWishByGuidWithPrivacyRow struct {
|
||||
ID int64
|
||||
Guid pgtype.UUID
|
||||
WishListID int64
|
||||
WishListGuid pgtype.UUID
|
||||
Name string
|
||||
Description string
|
||||
PictureUrl string
|
||||
Stars int16
|
||||
CreationDate pgtype.Timestamp
|
||||
Fulfilled bool
|
||||
FulfilledDate pgtype.Timestamp
|
||||
Deleted bool
|
||||
AccessAllowed bool
|
||||
}
|
||||
|
||||
// XXX: Obsolete, use the according access check query instead
|
||||
func (q *Queries) GetWishByGuidWithPrivacy(ctx context.Context, arg GetWishByGuidWithPrivacyParams) (GetWishByGuidWithPrivacyRow, error) {
|
||||
row := q.db.QueryRow(ctx, getWishByGuidWithPrivacy, arg.Requester, arg.Guid)
|
||||
var i GetWishByGuidWithPrivacyRow
|
||||
err := row.Scan(
|
||||
&i.ID,
|
||||
&i.Guid,
|
||||
&i.WishListID,
|
||||
&i.WishListGuid,
|
||||
&i.Name,
|
||||
&i.Description,
|
||||
&i.PictureUrl,
|
||||
&i.Stars,
|
||||
&i.CreationDate,
|
||||
&i.Fulfilled,
|
||||
&i.FulfilledDate,
|
||||
&i.Deleted,
|
||||
&i.AccessAllowed,
|
||||
)
|
||||
return i, err
|
||||
}
|
||||
|
||||
const getWishlistByGuid = `-- name: GetWishlistByGuid :one
|
||||
SELECT id, guid, profile_id, hidden, name, icon_name, color, color_grad, deleted FROM wish_lists wl
|
||||
WHERE wl.guid = ($1::text)::uuid
|
||||
@@ -933,11 +1109,93 @@ func (q *Queries) GetWishlistByGuid(ctx context.Context, guid string) (WishList,
|
||||
return i, err
|
||||
}
|
||||
|
||||
const getWishlistsByUsername = `-- name: GetWishlistsByUsername :many
|
||||
SELECT wl.id, guid, profile_id, hidden, wl.name, icon_name, wl.color, wl.color_grad, wl.deleted, p.id, user_id, p.name, bio, avatar_url, birthday, p.color, p.color_grad, u.id, username, verified, registration_date, role, u.deleted FROM wish_lists wl
|
||||
JOIN profiles p ON p.id = wl.profile_id
|
||||
JOIN users u ON u.id = p.user_id
|
||||
WHERE u.username = $1::text
|
||||
`
|
||||
|
||||
type GetWishlistsByUsernameRow struct {
|
||||
ID int64
|
||||
Guid pgtype.UUID
|
||||
ProfileID int64
|
||||
Hidden bool
|
||||
Name string
|
||||
IconName string
|
||||
Color string
|
||||
ColorGrad string
|
||||
Deleted bool
|
||||
ID_2 int64
|
||||
UserID int64
|
||||
Name_2 string
|
||||
Bio string
|
||||
AvatarUrl string
|
||||
Birthday pgtype.Timestamp
|
||||
Color_2 string
|
||||
ColorGrad_2 string
|
||||
ID_3 int64
|
||||
Username string
|
||||
Verified bool
|
||||
RegistrationDate pgtype.Timestamp
|
||||
Role int32
|
||||
Deleted_2 *bool
|
||||
}
|
||||
|
||||
func (q *Queries) GetWishlistsByUsername(ctx context.Context, username string) ([]GetWishlistsByUsernameRow, error) {
|
||||
rows, err := q.db.Query(ctx, getWishlistsByUsername, username)
|
||||
if err != nil {
|
||||
return nil, err
|
||||
}
|
||||
defer rows.Close()
|
||||
var items []GetWishlistsByUsernameRow
|
||||
for rows.Next() {
|
||||
var i GetWishlistsByUsernameRow
|
||||
if err := rows.Scan(
|
||||
&i.ID,
|
||||
&i.Guid,
|
||||
&i.ProfileID,
|
||||
&i.Hidden,
|
||||
&i.Name,
|
||||
&i.IconName,
|
||||
&i.Color,
|
||||
&i.ColorGrad,
|
||||
&i.Deleted,
|
||||
&i.ID_2,
|
||||
&i.UserID,
|
||||
&i.Name_2,
|
||||
&i.Bio,
|
||||
&i.AvatarUrl,
|
||||
&i.Birthday,
|
||||
&i.Color_2,
|
||||
&i.ColorGrad_2,
|
||||
&i.ID_3,
|
||||
&i.Username,
|
||||
&i.Verified,
|
||||
&i.RegistrationDate,
|
||||
&i.Role,
|
||||
&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 getWishlistsByUsernameWithPrivacy = `-- name: GetWishlistsByUsernameWithPrivacy :many
|
||||
SELECT
|
||||
wl.id, wl.guid, wl.profile_id, wl.hidden, wl.name, wl.icon_name, wl.color, wl.color_grad, wl.deleted,
|
||||
CASE
|
||||
WHEN (ps.hide_profile_details OR ps.hide_for_unauthenticated) THEN FALSE
|
||||
WHEN (
|
||||
ps.hide_profile_details OR (
|
||||
ps.hide_for_unauthenticated AND
|
||||
$1::text = ''
|
||||
)
|
||||
) THEN FALSE
|
||||
ELSE TRUE
|
||||
END AS access_allowed
|
||||
FROM
|
||||
@@ -950,9 +1208,9 @@ JOIN
|
||||
users AS u ON p.user_id = u.id
|
||||
WHERE
|
||||
wl.deleted IS FALSE AND
|
||||
u.username = $1::text AND
|
||||
u.username = $2::text AND
|
||||
(
|
||||
u.username = $2::text OR
|
||||
u.username = $1::text OR
|
||||
(u.verified IS TRUE AND
|
||||
NOT EXISTS (
|
||||
SELECT 1
|
||||
@@ -965,8 +1223,8 @@ WHERE
|
||||
`
|
||||
|
||||
type GetWishlistsByUsernameWithPrivacyParams struct {
|
||||
Username string
|
||||
Requester string
|
||||
Username string
|
||||
}
|
||||
|
||||
type GetWishlistsByUsernameWithPrivacyRow struct {
|
||||
@@ -982,8 +1240,9 @@ type GetWishlistsByUsernameWithPrivacyRow struct {
|
||||
AccessAllowed bool
|
||||
}
|
||||
|
||||
// XXX: Obsolete, use the according access check query instead
|
||||
func (q *Queries) GetWishlistsByUsernameWithPrivacy(ctx context.Context, arg GetWishlistsByUsernameWithPrivacyParams) ([]GetWishlistsByUsernameWithPrivacyRow, error) {
|
||||
rows, err := q.db.Query(ctx, getWishlistsByUsernameWithPrivacy, arg.Username, arg.Requester)
|
||||
rows, err := q.db.Query(ctx, getWishlistsByUsernameWithPrivacy, arg.Requester, arg.Username)
|
||||
if err != nil {
|
||||
return nil, err
|
||||
}
|
||||
|
||||
104
sqlc/query.sql
104
sqlc/query.sql
@@ -280,7 +280,27 @@ SELECT profiles.* FROM profiles
|
||||
JOIN users ON users.id = profiles.user_id
|
||||
WHERE users.username = $1;
|
||||
|
||||
;-- name: CheckProfileAccess :one
|
||||
-- XXX: recheck, was tired
|
||||
SELECT
|
||||
CASE WHEN u.deleted OR NOT u.verified THEN TRUE ELSE FALSE END AS user_unavailable,
|
||||
CASE WHEN EXISTS (
|
||||
SELECT 1
|
||||
FROM banned_users
|
||||
WHERE user_id = u.id AND
|
||||
pardoned IS FALSE AND
|
||||
(expires_at IS NULL OR expires_at < CURRENT_TIMESTAMP)
|
||||
) THEN TRUE ELSE FALSE END AS user_banned,
|
||||
CASE WHEN ps.hide_profile_details THEN TRUE ELSE FALSE END AS hidden,
|
||||
CASE WHEN ps.hide_for_unauthenticated AND @requester::text = '' THEN TRUE ELSE FALSE END AS auth_required,
|
||||
CASE WHEN ps.captcha THEN TRUE ELSE FALSE END AS captcha_required
|
||||
FROM profiles p
|
||||
JOIN profile_settings ps ON ps.profile_id = p.id
|
||||
JOIN users u ON p.user_id = u.id
|
||||
WHERE p.id = $1;
|
||||
|
||||
;-- name: GetProfileByUsernameWithPrivacy :one
|
||||
-- FIXME: tweak backend code to handle privacy correctly
|
||||
SELECT
|
||||
u.username,
|
||||
p.name,
|
||||
@@ -288,27 +308,13 @@ SELECT
|
||||
p.avatar_url,
|
||||
CASE WHEN ps.hide_birthday THEN NULL ELSE p.birthday END AS birthday,
|
||||
p.color,
|
||||
p.color_grad,
|
||||
NOT (@requester::text = '' AND ps.hide_for_unauthenticated) AS access_allowed
|
||||
p.color_grad
|
||||
FROM
|
||||
users AS u
|
||||
JOIN profiles AS p ON u.id = p.user_id
|
||||
JOIN profile_settings AS ps ON p.id = ps.profile_id
|
||||
WHERE
|
||||
u.username = @searched_username::text
|
||||
AND (
|
||||
@searched_username::text = @requester::text
|
||||
OR
|
||||
u.deleted IS FALSE
|
||||
AND u.verified IS TRUE
|
||||
AND NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM banned_users
|
||||
WHERE user_id = u.id AND
|
||||
pardoned IS FALSE AND
|
||||
(expires_at IS NULL OR expires_at < CURRENT_TIMESTAMP)
|
||||
)
|
||||
);
|
||||
u.username = @searched_username::text;
|
||||
|
||||
;-- name: GetProfilesRestricted :many
|
||||
SELECT
|
||||
@@ -389,11 +395,23 @@ WHERE wl.guid = (@guid::text)::uuid;
|
||||
SELECT * FROM wish_lists wl
|
||||
WHERE wl.guid = (@guid::text)::uuid;
|
||||
|
||||
;-- name: GetWishlistsByUsername :many
|
||||
SELECT * FROM wish_lists wl
|
||||
JOIN profiles p ON p.id = wl.profile_id
|
||||
JOIN users u ON u.id = p.user_id
|
||||
WHERE u.username = @username::text;
|
||||
|
||||
-- name: GetWishlistsByUsernameWithPrivacy :many
|
||||
-- XXX: Obsolete, create according access check query instead
|
||||
SELECT
|
||||
wl.*,
|
||||
CASE
|
||||
WHEN (ps.hide_profile_details OR ps.hide_for_unauthenticated) THEN FALSE
|
||||
WHEN (
|
||||
ps.hide_profile_details OR (
|
||||
ps.hide_for_unauthenticated AND
|
||||
@requester::text = ''
|
||||
)
|
||||
) THEN FALSE
|
||||
ELSE TRUE
|
||||
END AS access_allowed
|
||||
FROM
|
||||
@@ -423,6 +441,25 @@ WHERE
|
||||
|
||||
--: Wish Object {{{
|
||||
|
||||
;-- name: CreateWish :one
|
||||
INSERT INTO wishes(
|
||||
wish_list_id,
|
||||
wish_list_guid,
|
||||
name,
|
||||
description,
|
||||
picture_url,
|
||||
stars)
|
||||
VALUES
|
||||
(
|
||||
(SELECT id FROM wish_lists wl WHERE wl.guid = (@wish_list_guid::text)::uuid),
|
||||
(@wish_list_guid::text)::uuid,
|
||||
@name::text,
|
||||
@description::text,
|
||||
@picture_url::text,
|
||||
@stars::smallint
|
||||
)
|
||||
RETURNING *;
|
||||
|
||||
;-- name: UpdateWishByGuid :exec
|
||||
UPDATE wishes w
|
||||
SET
|
||||
@@ -454,4 +491,37 @@ WITH updated AS (
|
||||
SELECT
|
||||
COUNT(*) > 0 AS target_found
|
||||
FROM updated;
|
||||
|
||||
;-- name: GetWishByGuid :one
|
||||
SELECT * FROM wishes w
|
||||
WHERE w.guid = (@guid::text)::uuid;
|
||||
|
||||
;-- name: GetWishByGuidWithPrivacy :one
|
||||
-- XXX: Obsolete, create according access check query instead
|
||||
SELECT
|
||||
w.*,
|
||||
CASE
|
||||
WHEN
|
||||
(
|
||||
@requester::text = u.username OR
|
||||
NOT ps.hide_profile_details AND
|
||||
NOT
|
||||
(
|
||||
ps.hide_for_unauthenticated AND
|
||||
@requester::text = ''
|
||||
) AND
|
||||
NOT wl.hidden
|
||||
)
|
||||
THEN TRUE
|
||||
ELSE FALSE
|
||||
END AS access_allowed
|
||||
FROM wishes w
|
||||
JOIN wish_lists wl ON w.wish_list_id = wl.id
|
||||
JOIN profiles p ON wl.profile_id = p.id
|
||||
JOIN profile_settings ps ON ps.profile_id = p.id
|
||||
JOIN users u ON p.user_id = u.id
|
||||
WHERE
|
||||
w.guid = (@guid::text)::uuid AND
|
||||
w.deleted IS FALSE;
|
||||
|
||||
--: }}}
|
||||
|
||||
@@ -121,3 +121,63 @@ CREATE TABLE IF NOT EXISTS "wishes" (
|
||||
fulfilled_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
deleted BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_profile(requester_user_id BIGINT, target_profile_id BIGINT)
|
||||
RETURNS JSONB AS $$
|
||||
DECLARE
|
||||
profile_record profiles%ROWTYPE;
|
||||
settings_record profile_settings%ROWTYPE;
|
||||
is_owner BOOLEAN;
|
||||
is_banned BOOLEAN;
|
||||
is_deleted BOOLEAN;
|
||||
BEGIN
|
||||
-- Check if target user exists and is not deleted/banned
|
||||
SELECT p.*, u.deleted INTO profile_record
|
||||
FROM profiles p
|
||||
JOIN users u ON p.user_id = u.id
|
||||
WHERE p.id = target_profile_id;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
RETURN NULL; -- Or raise an exception for "not found"
|
||||
END IF;
|
||||
|
||||
is_deleted := profile_record.deleted; -- From users table
|
||||
IF is_deleted THEN
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
-- Check if requester is banned (simplified; expand as needed)
|
||||
SELECT EXISTS(SELECT 1 FROM banned_users WHERE user_id = requester_user_id AND pardoned = FALSE AND (expires_at IS NULL OR expires_at > CURRENT_TIMESTAMP)) INTO is_banned;
|
||||
IF is_banned THEN
|
||||
RAISE EXCEPTION 'Requester is banned';
|
||||
END IF;
|
||||
|
||||
-- Determine ownership
|
||||
is_owner := (profile_record.user_id = requester_user_id);
|
||||
|
||||
-- Fetch settings
|
||||
SELECT * INTO settings_record FROM profile_settings WHERE profile_id = target_profile_id;
|
||||
|
||||
-- Apply privacy: Hide for unauthenticated or based on settings
|
||||
IF requester_user_id IS NULL AND settings_record.hide_for_unauthenticated THEN -- NULL requester means unauth
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
IF NOT is_owner AND settings_record.hide_profile_details THEN
|
||||
RETURN NULL; -- Or return minimal public data
|
||||
END IF;
|
||||
|
||||
-- Sanitize fields based on settings
|
||||
IF NOT is_owner AND settings_record.hide_birthday THEN
|
||||
profile_record.birthday := NULL;
|
||||
END IF;
|
||||
-- Add more field-level masking here (e.g., bio, avatar_url)
|
||||
|
||||
-- Return as JSONB for easy app consumption
|
||||
RETURN row_to_json(profile_record)::JSONB;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RAISE NOTICE 'Access denied: %', SQLERRM;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
Reference in New Issue
Block a user