refactor: began refactoring access control in sql
This commit is contained in:
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