-- Copyright (c) 2025 Nikolai Papin -- -- This file is part of Easywish -- -- This program is free software: you can redistribute it and/or modify -- it under the terms of the GNU General Public License as published by -- the Free Software Foundation, either version 3 of the License, or -- (at your option) any later version. -- -- This program is distributed in the hope that it will be useful, -- but WITHOUT ANY WARRANTY; without even the implied warranty of -- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See -- the GNU General Public License for more details. -- -- You should have received a copy of the GNU General Public License -- along with this program. If not, see . ; CREATE EXTENSION IF NOT EXISTS "pgcrypto"; CREATE TABLE IF NOT EXISTS "users" ( id BIGSERIAL PRIMARY KEY, username VARCHAR(20) UNIQUE NOT NULL, verified BOOLEAN NOT NULL DEFAULT FALSE, registration_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, role INTEGER NOT NULL DEFAULT 1, -- enum user 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 NOT NULL DEFAULT FALSE, pardoned_by VARCHAR(20) ); CREATE TABLE IF NOT EXISTS "login_informations" ( id BIGSERIAL PRIMARY KEY, user_id BIGINT UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE, email VARCHAR(75) UNIQUE, password_hash VARCHAR(512) NOT NULL, totp_encrypted VARCHAR(512), email_2fa_enabled BOOLEAN DEFAULT FALSE, password_change_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS "confirmation_codes" ( id BIGSERIAL PRIMARY KEY, 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 NOT NULL DEFAULT FALSE, deleted BOOLEAN NOT NULL DEFAULT FALSE ); CREATE TABLE IF NOT EXISTS "sessions" ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, guid UUID UNIQUE NOT NULL DEFAULT gen_random_uuid(), name VARCHAR(175), platform VARCHAR(175), latest_ip VARCHAR(16), login_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, last_refresh_exp_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP + INTERVAL '10080 seconds', last_seen_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, terminated BOOLEAN DEFAULT FALSE ); 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) NOT NULL DEFAULT '', avatar_url VARCHAR(512) NOT NULL DEFAULT '', birthday TIMESTAMP, color VARCHAR(7) NOT NULL DEFAULT '#254333', color_grad VARCHAR(7) NOT NULL DEFAULT '#691E4D' ); 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 NOT NULL DEFAULT TRUE, hide_profile_details BOOLEAN NOT NULL DEFAULT FALSE, hide_for_unauthenticated BOOLEAN NOT NULL DEFAULT FALSE, hide_birthday BOOLEAN NOT NULL DEFAULT FALSE, hide_dates BOOLEAN NOT NULL DEFAULT FALSE, captcha BOOLEAN NOT NULL DEFAULT FALSE, followers_only_interaction BOOLEAN NOT NULL DEFAULT FALSE ); CREATE TABLE IF NOT EXISTS "wish_lists" ( id BIGSERIAL PRIMARY KEY, guid UUID UNIQUE NOT NULL DEFAULT gen_random_uuid(), profile_id BIGINT UNIQUE NOT NULL REFERENCES profiles(id) ON DELETE CASCADE, hidden BOOLEAN NOT NULL DEFAULT FALSE, name VARCHAR(32) NOT NULL DEFAULT 'Wishes', icon_name VARCHAR(64) NOT NULL DEFAULT '', color VARCHAR(7) NOT NULL DEFAULT '', color_grad VARCHAR(7) NOT NULL DEFAULT '', deleted BOOLEAN NOT NULL DEFAULT FALSE ); CREATE TABLE IF NOT EXISTS "wishes" ( id BIGSERIAL PRIMARY KEY, guid UUID UNIQUE NOT NULL DEFAULT gen_random_uuid(), wish_list_id BIGINT UNIQUE NOT NULL REFERENCES wish_lists(id) ON DELETE CASCADE, wish_list_guid UUID NOT NULL REFERENCES wish_lists(guid) ON DELETE CASCADE, name VARCHAR(64) NOT NULL DEFAULT 'New wish', description VARCHAR(1000) NOT NULL DEFAULT '', picture_url VARCHAR(512) NOT NULL DEFAULT '', stars SMALLINT NOT NULL DEFAULT 3 CHECK (stars BETWEEN 1 AND 5), creation_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, fulfilled BOOLEAN NOT NULL DEFAULT FALSE, 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;