init commit,
This commit is contained in:
178
99_references/beacon-main/supabase/config.toml
Normal file
178
99_references/beacon-main/supabase/config.toml
Normal file
@@ -0,0 +1,178 @@
|
||||
# A string used to distinguish different Supabase projects on the same host. Defaults to the
|
||||
# working directory name when running `supabase init`.
|
||||
project_id = "beacon"
|
||||
|
||||
[api]
|
||||
enabled = true
|
||||
# Port to use for the API URL.
|
||||
port = 54321
|
||||
# Schemas to expose in your API. Tables, views and stored procedures in this schema will get API
|
||||
# endpoints. `public` is always included.
|
||||
schemas = ["public", "graphql_public"]
|
||||
# Extra schemas to add to the search_path of every request. `public` is always included.
|
||||
extra_search_path = ["public", "extensions"]
|
||||
# The maximum number of rows returns from a view, table, or stored procedure. Limits payload size
|
||||
# for accidental or malicious requests.
|
||||
max_rows = 1000
|
||||
|
||||
[db]
|
||||
# Port to use for the local database URL.
|
||||
port = 54322
|
||||
# Port used by db diff command to initialize the shadow database.
|
||||
shadow_port = 54320
|
||||
# The database major version to use. This has to be the same as your remote database's. Run `SHOW
|
||||
# server_version;` on the remote database to check.
|
||||
major_version = 15
|
||||
|
||||
[db.pooler]
|
||||
enabled = false
|
||||
# Port to use for the local connection pooler.
|
||||
port = 54329
|
||||
# Specifies when a server connection can be reused by other clients.
|
||||
# Configure one of the supported pooler modes: `transaction`, `session`.
|
||||
pool_mode = "transaction"
|
||||
# How many server connections to allow per user/database pair.
|
||||
default_pool_size = 20
|
||||
# Maximum number of client connections allowed.
|
||||
max_client_conn = 100
|
||||
|
||||
[realtime]
|
||||
enabled = true
|
||||
# Bind realtime via either IPv4 or IPv6. (default: IPv4)
|
||||
# ip_version = "IPv6"
|
||||
# The maximum length in bytes of HTTP request headers. (default: 4096)
|
||||
# max_header_length = 4096
|
||||
|
||||
[studio]
|
||||
enabled = true
|
||||
# Port to use for Supabase Studio.
|
||||
port = 54323
|
||||
# External URL of the API server that frontend connects to.
|
||||
api_url = "http://127.0.0.1"
|
||||
# OpenAI API Key to use for Supabase AI in the Supabase Studio.
|
||||
openai_api_key = "env(OPENAI_API_KEY)"
|
||||
|
||||
# Email testing server. Emails sent with the local dev setup are not actually sent - rather, they
|
||||
# are monitored, and you can view the emails that would have been sent from the web interface.
|
||||
[inbucket]
|
||||
enabled = true
|
||||
# Port to use for the email testing server web interface.
|
||||
port = 54324
|
||||
# Uncomment to expose additional ports for testing user applications that send emails.
|
||||
# smtp_port = 54325
|
||||
# pop3_port = 54326
|
||||
|
||||
[storage]
|
||||
enabled = true
|
||||
# The maximum file size allowed (e.g. "5MB", "500KB").
|
||||
file_size_limit = "50MiB"
|
||||
|
||||
[storage.image_transformation]
|
||||
enabled = true
|
||||
|
||||
[auth]
|
||||
enabled = true
|
||||
# The base URL of your website. Used as an allow-list for redirects and for constructing URLs used
|
||||
# in emails.
|
||||
site_url = "http://127.0.0.1:3000"
|
||||
# A list of *exact* URLs that auth providers are permitted to redirect to post authentication.
|
||||
additional_redirect_urls = ["https://127.0.0.1:3000"]
|
||||
# How long tokens are valid for, in seconds. Defaults to 3600 (1 hour), maximum 604,800 (1 week).
|
||||
jwt_expiry = 3600
|
||||
# If disabled, the refresh token will never expire.
|
||||
enable_refresh_token_rotation = true
|
||||
# Allows refresh tokens to be reused after expiry, up to the specified interval in seconds.
|
||||
# Requires enable_refresh_token_rotation = true.
|
||||
refresh_token_reuse_interval = 10
|
||||
# Allow/disallow new user signups to your project.
|
||||
enable_signup = true
|
||||
# Allow/disallow anonymous sign-ins to your project.
|
||||
enable_anonymous_sign_ins = false
|
||||
# Allow/disallow testing manual linking of accounts
|
||||
enable_manual_linking = false
|
||||
|
||||
[auth.email]
|
||||
# Allow/disallow new user signups via email to your project.
|
||||
enable_signup = true
|
||||
# If enabled, a user will be required to confirm any email change on both the old, and new email
|
||||
# addresses. If disabled, only the new email is required to confirm.
|
||||
double_confirm_changes = true
|
||||
# If enabled, users need to confirm their email address before signing in.
|
||||
enable_confirmations = false
|
||||
# Controls the minimum amount of time that must pass before sending another signup confirmation or password reset email.
|
||||
max_frequency = "1s"
|
||||
|
||||
# Uncomment to customize email template
|
||||
# [auth.email.template.invite]
|
||||
# subject = "You have been invited"
|
||||
# content_path = "./supabase/templates/invite.html"
|
||||
|
||||
[auth.sms]
|
||||
# Allow/disallow new user signups via SMS to your project.
|
||||
enable_signup = true
|
||||
# If enabled, users need to confirm their phone number before signing in.
|
||||
enable_confirmations = false
|
||||
# Template for sending OTP to users
|
||||
template = "Your code is {{ `{{ .Code }}` }} ."
|
||||
# Controls the minimum amount of time that must pass before sending another sms otp.
|
||||
max_frequency = "5s"
|
||||
|
||||
# Use pre-defined map of phone number to OTP for testing.
|
||||
# [auth.sms.test_otp]
|
||||
# 4152127777 = "123456"
|
||||
|
||||
# This hook runs before a token is issued and allows you to add additional claims based on the authentication method used.
|
||||
# [auth.hook.custom_access_token]
|
||||
# enabled = true
|
||||
# uri = "pg-functions://<database>/<schema>/<hook_name>"
|
||||
|
||||
# Configure one of the supported SMS providers: `twilio`, `twilio_verify`, `messagebird`, `textlocal`, `vonage`.
|
||||
[auth.sms.twilio]
|
||||
enabled = false
|
||||
account_sid = ""
|
||||
message_service_sid = ""
|
||||
# DO NOT commit your Twilio auth token to git. Use environment variable substitution instead:
|
||||
auth_token = "env(SUPABASE_AUTH_SMS_TWILIO_AUTH_TOKEN)"
|
||||
|
||||
# Use an external OAuth provider. The full list of providers are: `apple`, `azure`, `bitbucket`,
|
||||
# `discord`, `facebook`, `github`, `gitlab`, `google`, `keycloak`, `linkedin_oidc`, `notion`, `twitch`,
|
||||
# `twitter`, `slack`, `spotify`, `workos`, `zoom`.
|
||||
[auth.external.apple]
|
||||
enabled = false
|
||||
client_id = ""
|
||||
# DO NOT commit your OAuth provider secret to git. Use environment variable substitution instead:
|
||||
secret = "env(SUPABASE_AUTH_EXTERNAL_APPLE_SECRET)"
|
||||
# Overrides the default auth redirectUrl.
|
||||
redirect_uri = ""
|
||||
# Overrides the default auth provider URL. Used to support self-hosted gitlab, single-tenant Azure,
|
||||
# or any other third-party OIDC providers.
|
||||
url = ""
|
||||
# If enabled, the nonce check will be skipped. Required for local sign in with Google auth.
|
||||
skip_nonce_check = false
|
||||
|
||||
[edge_runtime]
|
||||
enabled = true
|
||||
# Configure one of the supported request policies: `oneshot`, `per_worker`.
|
||||
# Use `oneshot` for hot reload, or `per_worker` for load testing.
|
||||
policy = "oneshot"
|
||||
inspector_port = 8083
|
||||
|
||||
[analytics]
|
||||
enabled = false
|
||||
port = 54327
|
||||
vector_port = 54328
|
||||
# Configure one of the supported backends: `postgres`, `bigquery`.
|
||||
backend = "postgres"
|
||||
|
||||
# # Experimental features may be deprecated any time
|
||||
# [experimental]
|
||||
# # Configures Postgres storage engine to use OrioleDB (S3)
|
||||
# orioledb_version = "{{if .UseOrioleDB}}15.1.0.150{{end}}"
|
||||
# # Configures S3 bucket URL, eg. <bucket_name>.s3-<region>.amazonaws.com
|
||||
# s3_host = "env(S3_HOST)"
|
||||
# # Configures S3 bucket region, eg. us-east-1
|
||||
# s3_region = "env(S3_REGION)"
|
||||
# # Configures AWS_ACCESS_KEY_ID for S3 bucket
|
||||
# s3_access_key = "env(S3_ACCESS_KEY)"
|
||||
# # Configures AWS_SECRET_ACCESS_KEY for S3 bucket
|
||||
# s3_secret_key = "env(S3_SECRET_KEY)"
|
@@ -0,0 +1,52 @@
|
||||
/**
|
||||
* Setup miscellaneous things before the main setup
|
||||
*/
|
||||
|
||||
/* --------------------------------------- Setup schemas --------------------------------------- */
|
||||
|
||||
-- Utilities (Non-public helpers)
|
||||
CREATE SCHEMA IF NOT EXISTS utilities;
|
||||
|
||||
/* -------------------------------------- Setup extensions ------------------------------------- */
|
||||
|
||||
-- PostGIS
|
||||
CREATE EXTENSION
|
||||
IF NOT EXISTS postgis
|
||||
WITH SCHEMA extensions;
|
||||
|
||||
-- pg_cron
|
||||
CREATE EXTENSION
|
||||
IF NOT EXISTS pg_cron
|
||||
WITH SCHEMA extensions;
|
||||
|
||||
GRANT USAGE ON SCHEMA cron TO postgres;
|
||||
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA cron TO postgres;
|
||||
|
||||
/* --------------------------------------- Setup buckets --------------------------------------- */
|
||||
|
||||
-- Media
|
||||
INSERT INTO storage.buckets (
|
||||
id,
|
||||
name,
|
||||
public,
|
||||
file_size_limit,
|
||||
allowed_mime_types
|
||||
) VALUES (
|
||||
'media',
|
||||
'media',
|
||||
TRUE,
|
||||
4194304, -- 4 MiB
|
||||
ARRAY[
|
||||
-- Images
|
||||
'image/avif',
|
||||
'image/gif',
|
||||
'image/jpeg',
|
||||
'image/png',
|
||||
'image/webp',
|
||||
|
||||
-- Videos
|
||||
'video/mp4',
|
||||
'video/mpeg',
|
||||
'video/webm'
|
||||
]
|
||||
);
|
@@ -0,0 +1,664 @@
|
||||
/**
|
||||
* Setup routines
|
||||
*/
|
||||
|
||||
/* ---------------------------------- Private utility routines --------------------------------- */
|
||||
|
||||
-- Generate a random double precision number between 0 (inclusive) and 1 (exclusive), using crypto-safe random data
|
||||
--
|
||||
-- This function has been verified to produce a uniform distribution of values using a one-sample Kolmogorov-Smirnov
|
||||
-- test with a null hypothesis of perfect uniform distribution with a p value of exactly 0.0 (Less round-off errors)
|
||||
-- for a sample size of 1 million.
|
||||
--
|
||||
-- Note that because this function uses rejection-sampling, timing attacks are hypothetically possible, especially
|
||||
-- if the RNG is predictable (Though that in itself represents a rather grave security concern).
|
||||
CREATE OR REPLACE FUNCTION utilities.safe_random()
|
||||
RETURNS DOUBLE PRECISION
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Maximum value of a BIGINT as a double precision number
|
||||
_max CONSTANT DOUBLE PRECISION := (~(1::BIGINT << 63))::DOUBLE PRECISION;
|
||||
|
||||
-- Current random value
|
||||
_value DOUBLE PRECISION;
|
||||
BEGIN
|
||||
LOOP
|
||||
-- Generate 8 crypto-safe random bytes, convert them to a bit string, set the MSB to 0 (Make positive), convert to a double, and normalize
|
||||
_value = SET_BIT(RIGHT(extensions.gen_random_bytes(8)::TEXT, -1)::BIT(64), 0, 0)::BIGINT::DOUBLE PRECISION / _max;
|
||||
|
||||
-- Return if the value is not 1 (The probability of this happening is very close to 0, but this guarentees the returned value is never 1)
|
||||
IF _value < 1 THEN
|
||||
RETURN _value;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Get a random color
|
||||
CREATE OR REPLACE FUNCTION utilities.get_random_color()
|
||||
RETURNS TEXT
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Possible colors (Select Tailwind colors using the 300, 500, and 800 variants; similar colors have been removed)
|
||||
_colors CONSTANT TEXT[] := ARRAY[
|
||||
-- Reds
|
||||
'#fca5a5', '#ef4444', '#991b1b',
|
||||
|
||||
-- Oranges
|
||||
'#fdba74', '#f97316', '#9a3412',
|
||||
|
||||
-- Yellows
|
||||
'#fde047', '#eab308', '#854d0e',
|
||||
|
||||
-- Limes
|
||||
'#bef264', '#84cc16', '#3f6212',
|
||||
|
||||
-- Greens
|
||||
'#86efac', '#22c55e', '#166534',
|
||||
|
||||
-- Teals
|
||||
'#5eead4', '#14b8a6', '#115e59',
|
||||
|
||||
-- Skies
|
||||
'#7dd3fc', '#0ea5e9', '#075985',
|
||||
|
||||
-- Blues
|
||||
'#93c5fd', '#3b82f6', '#1e40af',
|
||||
|
||||
-- Indigos
|
||||
'#a5b4fc', '#6366f1', '#3730a3',
|
||||
|
||||
-- Purples
|
||||
'#d8b4fe', '#a855f7', '#6b21a8',
|
||||
|
||||
-- Fuchsias
|
||||
'#f0abfc', '#d946ef', '#86198f'
|
||||
];
|
||||
|
||||
-- Color length
|
||||
_color_length CONSTANT INTEGER := ARRAY_LENGTH(_colors, 1);
|
||||
BEGIN
|
||||
RETURN _colors[FLOOR(utilities.safe_random() * _color_length) + 1];
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Get a random emoji
|
||||
CREATE OR REPLACE FUNCTION utilities.get_random_emoji()
|
||||
RETURNS TEXT
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Possible emojis (Similar, hard-to-identify, or any other emojis that would otherwise be strange to use for an avatar have been removed)
|
||||
_emojis CONSTANT TEXT[] := ARRAY[
|
||||
'⌚️', '⏰', '⏳', '☀️', '☁️', '☢️', '☣️', '♻️', '⚓️', '⚛️', '⚠️', '⚡️', '⚽️', '⚾️', '⛄️', '⛏', '⛔️', '⛩', '⛰', '⛱', '⛳️', '⛵️', '⛸', '✂️', '✅', '✈️', '❄️', '❌', '❎', '❓', '❗️', '❤️', '⭐️', '⭕️', '🌈', '🌊', '🌋', '🌎', '🌐', '🌑', '🌕', '🌗', '🌡', '🌪', '🌱', '🌲', '🌳', '🌴', '🌵', '🌶', '🌷', '🌻', '🌽', '🍀', '🍁', '🍂', '🍄', '🍅', '🍆', '🍇', '🍉', '🍊', '🍋', '🍌', '🍍', '🍎', '🍐', '🍑', '🍒', '🍓', '🍥', '🍦', '🍩', '🍪', '🍫', '🍬', '🍭', '🍰', '🍷', '🍸', '🍺', '🍿', '🎀', '🎁', '🎃', '🎈', '🎉', '🎗', '🎟', '🎡', '🎢', '🎤', '🎥', '🎧', '🎨', '🎩', '🎪', '🎬', '🎭', '🎮', '🎯', '🎰', '🎱', '🎲', '🎳', '🎵', '🎷', '🎸', '🎹', '🎺', '🎻', '🏀', '🏅', '🏆', '🏈', '🏉', '🏍', '🏐', '🏓', '🏕', '🏗', '🏝', '🏟', '🏠', '🏢', '🏭', '🏮', '🏯', '🏰', '🏹', '🐁', '🐅', '🐇', '🐊', '🐌', '🐍', '🐏', '🐐', '🐑', '🐓', '🐔', '🐗', '🐘', '🐙', '🐚', '🐛', '🐜', '🐝', '🐞', '🐟', '🐡', '🐢', '🐤', '🐦', '🐦⬛', '🐧', '🐨', '🐫', '🐬', '🐭', '🐮', '🐯', '🐰', '🐱', '🐳', '🐴', '🐵', '🐶', '🐷', '🐸', '🐹', '🐺', '🐻', '🐻❄️', '🐼', '🐿', '👑', '👽', '💀', '💈', '💎', '💙', '💚', '💜', '💡', '💢', '💣', '💥', '💧', '💯', '💰', '💵', '💸', '📈', '📉', '📌', '📎', '📜', '📡', '📣', '📦', '📫', '📸', '🔆', '🔊', '🔍', '🔑', '🔒', '🔔', '🔗', '🔥', '🔦', '🔩', '🔪', '🔫', '🔬', '🔭', '🔮', '🔱', '🕷', '🕹', '🖊', '🖌', '🖍', '🖤', '🗡', '🗺', '🗻', '🗼', '🗽', '🗿', '🚀', '🚂', '🚌', '🚑', '🚒', '🚓', '🚕', '🚗', '🚜', '🚦', '🚧', '🚨', '🚫', '🚲', '🛍️', '🛑', '🛟', '🛠', '🛡', '🛥', '🛰', '🛳', '🛴', '🛶', '🛷', '🛸', '🛹', '🛻', '🛼', '🤖', '🤿', '🥁', '🥊', '🥏', '🥐', '🥑', '🥕', '🥚', '🥝', '🥥', '🥧', '🥨', '🥭', '🥯', '🦀', '🦁', '🦂', '🦄', '🦅', '🦆', '🦇', '🦈', '🦉', '🦊', '🦋', '🦌', '🦍', '🦎', '🦏', '🦒', '🦓', '🦔', '🦕', '🦘', '🦙', '🦚', '🦛', '🦜', '🦝', '🦠', '🦣', '🦥', '🦦', '🦨', '🦩', '🦫', '🦬', '🧀', '🧁', '🧡', '🧨', '🧩', '🧬', '🧭', '🧯', '🧲', '🧸', '🩵', '🩷', '🪀', '🪁', '🪂', '🪄', '🪅', '🪇', '🪈', '🪐', '🪓', '🪗', '🪘', '🪚', '🪦', '🪩', '🪱', '🪴', '🪵', '🪸', '🪼', '🪽', '🪿', '🫏', '🫐', '🫑'
|
||||
];
|
||||
|
||||
-- Emoji length
|
||||
_emoji_length CONSTANT INTEGER := ARRAY_LENGTH(_emojis, 1);
|
||||
BEGIN
|
||||
RETURN _emojis[FLOOR(utilities.safe_random() * _emoji_length) + 1];
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Prune expired locations trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.prune_expired_locations()
|
||||
RETURNS VOID
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Expiration interval
|
||||
_interval CONSTANT INTERVAL := INTERVAL '1 hour';
|
||||
BEGIN
|
||||
-- Delete expired locations
|
||||
DELETE FROM public.locations
|
||||
WHERE created_at < (NOW() - _interval);
|
||||
END;
|
||||
$$;
|
||||
|
||||
/* -------------------------------------- Trigger routines ------------------------------------- */
|
||||
|
||||
-- Prune locations trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.prune_locations_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Expiration interval
|
||||
_interval CONSTANT INTERVAL := INTERVAL '1 hour';
|
||||
BEGIN
|
||||
-- Keep only 5 newest locations that haven't expired for the user
|
||||
DELETE FROM public.locations
|
||||
WHERE
|
||||
user_id = NEW.user_id AND
|
||||
created_at < (NOW() - _interval) AND
|
||||
id NOT IN (
|
||||
SELECT id
|
||||
FROM public.locations
|
||||
ORDER BY created_at DESC
|
||||
LIMIT 5
|
||||
);
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Setup a profile for a new user trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.setup_profile_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Insert a new profile for the user
|
||||
INSERT INTO public.profiles (
|
||||
id
|
||||
) VALUES (
|
||||
NEW.id
|
||||
);
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Validate a new location trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.validate_location_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Previous created at
|
||||
_previous_created_at TIMESTAMPTZ;
|
||||
|
||||
-- Previous location
|
||||
_previous_location extensions.GEOGRAPHY(POINT, 4326);
|
||||
|
||||
-- The _elapsed time (in seconds) between the new location and the previous location
|
||||
_elapsed BIGINT;
|
||||
|
||||
-- The _distance (in meters) between the new location and the previous location
|
||||
_distance DOUBLE PRECISION;
|
||||
BEGIN
|
||||
-- Get the previous created at and location
|
||||
SELECT created_at, location INTO _previous_created_at, _previous_location
|
||||
FROM public.locations
|
||||
WHERE user_id = NEW.user_id
|
||||
ORDER BY created_at DESC
|
||||
LIMIT 1;
|
||||
|
||||
-- Return if there is no previous created at/location
|
||||
IF _previous_created_at IS NULL AND _previous_location IS NULL THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- Calculate the _elapsed time between the new location and the previous location
|
||||
SELECT EXTRACT(EPOCH FROM (NEW.created_at - _previous_created_at)) INTO _elapsed;
|
||||
|
||||
-- Skip inserting if the elapsed time is zero
|
||||
IF _elapsed = 0::BIGINT THEN
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
-- Calculate the distance between the new location and the previous location
|
||||
SELECT extensions.ST_Distance(NEW.location, _previous_location) INTO _distance;
|
||||
|
||||
-- Prevent the user from moving too fast (> 1200 km/h ~= 333.333 m/s)
|
||||
IF (_distance / _elapsed::DOUBLE PRECISION) > 333.333 THEN
|
||||
RAISE EXCEPTION 'You are moving too fast';
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Anonymize the location of a new post trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.anonymize_location_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
_uncertainty DOUBLE PRECISION := 0.10;
|
||||
|
||||
-- Old location as a geometry point
|
||||
_old_location extensions.GEOMETRY;
|
||||
BEGIN
|
||||
-- Convert the old location to a geometry point
|
||||
_old_location = NEW.private_location::extensions.GEOMETRY;
|
||||
|
||||
-- Add some uncertainty relative to the post's radius (To increase resistance against static trilateration attacks)
|
||||
NEW.private_location = extensions.ST_Project(
|
||||
_old_location::extensions.GEOGRAPHY,
|
||||
(-(_uncertainty / 2) * NEW.radius) + (_uncertainty * NEW.radius * utilities.safe_random()),
|
||||
2 * PI() * utilities.safe_random()
|
||||
);
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Post deleted trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.post_deleted_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Delete the media
|
||||
IF OLD.has_media THEN
|
||||
DELETE FROM storage.objects
|
||||
WHERE bucket_id = 'media'
|
||||
AND name = 'posts/' || OLD.id::TEXT;
|
||||
END IF;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Post view modified (i.e.: insert, update, or delete) trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.post_view_modified_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Post ID
|
||||
_post_id UUID := CASE WHEN NEW IS NULL THEN OLD.post_id ELSE NEW.post_id END;
|
||||
BEGIN
|
||||
-- Recalculate post views
|
||||
UPDATE public.posts
|
||||
SET views = (
|
||||
SELECT COUNT(*)
|
||||
FROM public.post_views
|
||||
WHERE post_id = _post_id
|
||||
)
|
||||
WHERE id = _post_id;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Post vote modified (i.e.: insert, update, or delete) trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.post_vote_modified_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Post ID
|
||||
_post_id UUID := CASE WHEN NEW IS NULL THEN OLD.post_id ELSE NEW.post_id END;
|
||||
|
||||
-- Post upvotes
|
||||
_upvotes BIGINT;
|
||||
|
||||
-- Post downvotes
|
||||
_downvotes BIGINT;
|
||||
BEGIN
|
||||
-- Recalculate post votes
|
||||
SELECT
|
||||
COALESCE(SUM(CASE WHEN upvote THEN 1 ELSE 0 END), 0),
|
||||
COALESCE(SUM(CASE WHEN NOT upvote THEN 1 ELSE 0 END), 0)
|
||||
INTO _upvotes, _downvotes
|
||||
FROM public.post_votes
|
||||
WHERE post_id = _post_id;
|
||||
|
||||
-- Update the post
|
||||
UPDATE public.posts
|
||||
SET
|
||||
upvotes = _upvotes,
|
||||
downvotes = _downvotes
|
||||
WHERE id = _post_id;
|
||||
|
||||
-- Delete the post if the net votes is less than or equal to -5
|
||||
IF (_upvotes - _downvotes) <= -5 THEN
|
||||
DELETE FROM public.posts
|
||||
WHERE id = _post_id;
|
||||
END IF;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comment modified (i.e.: insert, update, or delete) trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.comment_modified_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Comment ID
|
||||
_id UUID := CASE WHEN NEW IS NULL THEN OLD.id ELSE NEW.id END;
|
||||
|
||||
-- Comment post ID
|
||||
_post_id UUID := CASE WHEN NEW IS NULL THEN OLD.post_id ELSE NEW.post_id END;
|
||||
|
||||
-- Current ancestor comment ID
|
||||
_ancestor_id UUID := CASE WHEN NEW IS NULL THEN OLD.parent_id ELSE NEW.parent_id END;
|
||||
|
||||
-- Ancestor comment IDs
|
||||
_ancestor_ids UUID[];
|
||||
BEGIN
|
||||
-- Recalculate post comments
|
||||
UPDATE public.posts
|
||||
SET comments = (
|
||||
SELECT COUNT(*)
|
||||
FROM public.comments
|
||||
WHERE post_id = _post_id
|
||||
)
|
||||
WHERE id = _post_id;
|
||||
|
||||
-- Add the comment ID to the ancestor IDs
|
||||
_ancestor_ids = array_append(_ancestor_ids, _id);
|
||||
|
||||
-- Check for different posts, repeated comments, and calculate the depth
|
||||
FOR i IN 0..9 LOOP
|
||||
-- Reached the top-level comment
|
||||
IF _ancestor_id IS NULL THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- Ensure the ancestor comment's post matches the child comment's post
|
||||
IF (
|
||||
SELECT post_id
|
||||
FROM public.comments
|
||||
WHERE id = _ancestor_id
|
||||
) != _post_id THEN
|
||||
RAISE EXCEPTION 'The ancestor''s comment''s post does not match the child comment''s post';
|
||||
END IF;
|
||||
|
||||
-- Check for repeated comments
|
||||
IF _ancestor_id = ANY(_ancestor_ids) THEN
|
||||
RAISE EXCEPTION 'The ancestor comment is repeated';
|
||||
END IF;
|
||||
|
||||
-- Add the parent ID to the ancestor IDs
|
||||
_ancestor_ids = array_append(_ancestor_ids, _ancestor_id);
|
||||
|
||||
-- Get the next parent ID
|
||||
SELECT parent_id INTO _ancestor_id
|
||||
FROM public.comments
|
||||
WHERE id = _ancestor_id;
|
||||
END LOOP;
|
||||
|
||||
-- Comment depth too deep
|
||||
RAISE EXCEPTION 'This comment is too many levels deep';
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comment view modified (i.e.: insert, update, or delete) trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.comment_view_modified_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Comment ID
|
||||
_comment_id UUID := CASE WHEN NEW IS NULL THEN OLD.comment_id ELSE NEW.comment_id END;
|
||||
BEGIN
|
||||
-- Recalculate comment views
|
||||
UPDATE public.comments
|
||||
SET views = (
|
||||
SELECT COUNT(*)
|
||||
FROM public.comment_views
|
||||
WHERE comment_id = _comment_id
|
||||
)
|
||||
WHERE id = _comment_id;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comment vote modified (i.e.: insert, update, or delete) trigger function
|
||||
CREATE OR REPLACE FUNCTION utilities.comment_vote_modified_trigger()
|
||||
RETURNS TRIGGER
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Comment ID
|
||||
_comment_id UUID := CASE WHEN NEW IS NULL THEN OLD.comment_id ELSE NEW.comment_id END;
|
||||
|
||||
-- Comment upvotes
|
||||
_upvotes BIGINT;
|
||||
|
||||
-- Comment downvotes
|
||||
_downvotes BIGINT;
|
||||
BEGIN
|
||||
-- Recalculate comment votes
|
||||
SELECT
|
||||
COALESCE(SUM(CASE WHEN upvote THEN 1 ELSE 0 END), 0),
|
||||
COALESCE(SUM(CASE WHEN NOT upvote THEN 1 ELSE 0 END), 0)
|
||||
INTO _upvotes, _downvotes
|
||||
FROM public.comment_votes
|
||||
WHERE comment_id = _comment_id;
|
||||
|
||||
-- Update the comment
|
||||
UPDATE public.comments
|
||||
SET
|
||||
upvotes = _upvotes,
|
||||
downvotes = _downvotes
|
||||
WHERE id = _comment_id;
|
||||
|
||||
-- Delete the comment if the net votes is less than or equal to -5
|
||||
IF (_upvotes - _downvotes) <= -5 THEN
|
||||
DELETE FROM public.comments
|
||||
WHERE id = _comment_id;
|
||||
END IF;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
/* -------------------------------------- Public routines -------------------------------------- */
|
||||
|
||||
-- Validate access to a post
|
||||
CREATE OR REPLACE FUNCTION public.validate_post_access(
|
||||
_post_id UUID
|
||||
)
|
||||
RETURNS BOOLEAN
|
||||
SECURITY DEFINER
|
||||
STABLE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN EXISTS (
|
||||
SELECT 1
|
||||
FROM public.posts post
|
||||
WHERE
|
||||
-- Only get the specified post
|
||||
post.id = _post_id
|
||||
|
||||
AND (
|
||||
-- Only get posts for which the current user is the poster
|
||||
post.private_poster_id = auth.uid()
|
||||
|
||||
-- Or only get posts for which the user is within the post's radius
|
||||
OR public.distance_to(post.private_location) <= post.radius
|
||||
)
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Validate a media object name
|
||||
CREATE OR REPLACE FUNCTION public.validate_media_object_name(
|
||||
_object_name TEXT
|
||||
)
|
||||
RETURNS BOOLEAN
|
||||
SECURITY DEFINER
|
||||
STABLE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Parsed name segments
|
||||
_segments TEXT[];
|
||||
BEGIN
|
||||
-- Parse the name
|
||||
_segments = STRING_TO_ARRAY(_object_name, '/');
|
||||
|
||||
-- Return false if the name has an incorrect number of segments
|
||||
IF ARRAY_LENGTH(_segments, 1) != 2 THEN
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
|
||||
-- Posts category
|
||||
IF _segments[1] = 'posts' THEN
|
||||
-- Check that the current user owns the corresponding post and that the post should have media
|
||||
RETURN EXISTS(
|
||||
SELECT 1
|
||||
FROM public.posts
|
||||
WHERE
|
||||
private_poster_id = auth.uid()
|
||||
AND has_media = TRUE
|
||||
AND id = _segments[2]::UUID
|
||||
);
|
||||
|
||||
-- Unknown media category
|
||||
ELSE
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Delete a user's account
|
||||
CREATE OR REPLACE FUNCTION public.delete_account()
|
||||
RETURNS VOID
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Delete the user's account
|
||||
DELETE FROM auth.users
|
||||
WHERE id = auth.uid();
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Calculate the distance from the current user's location to a specified location
|
||||
CREATE OR REPLACE FUNCTION public.distance_to(
|
||||
-- Other location to calculate the distance to
|
||||
_other_location extensions.GEOGRAPHY(POINT, 4326)
|
||||
)
|
||||
RETURNS DOUBLE PRECISION
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Current user's location
|
||||
_user_location extensions.GEOGRAPHY(POINT, 4326) := public.get_latest_location();
|
||||
BEGIN
|
||||
RETURN extensions.ST_Distance(_user_location, _other_location);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Get the latest location for the current user, raising an exception if there's no previous location or if the previous location is too old
|
||||
CREATE OR REPLACE FUNCTION public.get_latest_location()
|
||||
RETURNS extensions.GEOGRAPHY(POINT, 4326)
|
||||
SECURITY DEFINER
|
||||
VOLATILE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Created at
|
||||
_created_at TIMESTAMPTZ;
|
||||
|
||||
-- Location
|
||||
_location extensions.GEOGRAPHY(POINT, 4326);
|
||||
BEGIN
|
||||
-- Get the latest location
|
||||
SELECT created_at, location INTO _created_at, _location
|
||||
FROM public.locations
|
||||
WHERE user_id = auth.uid()
|
||||
ORDER BY created_at DESC
|
||||
LIMIT 1;
|
||||
|
||||
-- No previous location
|
||||
IF _created_at IS NULL AND _location IS NULL THEN
|
||||
RAISE EXCEPTION 'You do not have a location set';
|
||||
END IF;
|
||||
|
||||
-- Previous location too old
|
||||
IF _created_at < (NOW() - INTERVAL '1 hour') THEN
|
||||
RAISE EXCEPTION 'Your location is too old';
|
||||
END IF;
|
||||
|
||||
RETURN _location;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Calculate the rank of a post
|
||||
CREATE OR REPLACE FUNCTION public.calculate_rank(
|
||||
-- Distance to the post (In meters)
|
||||
_distance DOUBLE PRECISION,
|
||||
|
||||
-- Post score (Upvotes - downvotes)
|
||||
_score BIGINT,
|
||||
|
||||
-- Post created at
|
||||
_created_at TIMESTAMPTZ
|
||||
)
|
||||
RETURNS BIGINT
|
||||
IMMUTABLE
|
||||
LANGUAGE plpgsql
|
||||
SET search_path = ''
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Ranking scale factor
|
||||
_scale DOUBLE PRECISION := 10000;
|
||||
|
||||
-- Distance weight factor
|
||||
_distance_weight DOUBLE PRECISION := 5;
|
||||
|
||||
-- Maximum distance to be considered (In meters)
|
||||
_distance_range DOUBLE PRECISION := 5000;
|
||||
|
||||
-- Minimum score threshold
|
||||
_score_threshold BIGINT := -5;
|
||||
|
||||
-- Age weight factor
|
||||
_age_weight DOUBLE PRECISION := 1.075;
|
||||
BEGIN
|
||||
RETURN FLOOR(
|
||||
_scale *
|
||||
((_distance_weight - 1) * POWER(LEAST(1, _distance / _distance_range) - 1, 2) + 1) *
|
||||
LOG(GREATEST(1, _score - _score_threshold + 1)) *
|
||||
POWER(_age_weight, -EXTRACT(EPOCH FROM (NOW() - _created_at)) / 3600)
|
||||
)::BIGINT;
|
||||
END;
|
||||
$$;
|
@@ -0,0 +1,241 @@
|
||||
/**
|
||||
* Setup tables
|
||||
*/
|
||||
|
||||
/* ---------------------------------------- Setup tables --------------------------------------- */
|
||||
|
||||
-- Profiles (Exposed to other users)
|
||||
CREATE TABLE public.profiles (
|
||||
-- Primary key (Foreign key to auth.users)
|
||||
id UUID NOT NULL PRIMARY KEY REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Random color
|
||||
color TEXT NOT NULL DEFAULT utilities.get_random_color(),
|
||||
|
||||
-- Random emoji
|
||||
emoji TEXT NOT NULL DEFAULT utilities.get_random_emoji()
|
||||
);
|
||||
|
||||
-- User locations
|
||||
CREATE TABLE public.locations (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- User ID (Foreign key to auth.users)
|
||||
user_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Location (EPSG4326 - used by the W3C geolocation API)
|
||||
location extensions.GEOGRAPHY(POINT, 4326) NOT NULL
|
||||
);
|
||||
|
||||
-- Posts
|
||||
CREATE TABLE public.posts (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Private poster user ID (Foreign key to auth.users)
|
||||
private_poster_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Whether or not the post is anonymous
|
||||
private_anonymous BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
|
||||
-- Public poster ID (Only show if the post is not anonymous)
|
||||
poster_id UUID NULL GENERATED ALWAYS AS (
|
||||
CASE WHEN private_anonymous THEN NULL ELSE private_poster_id END
|
||||
) STORED,
|
||||
|
||||
-- Private post filter location (EPSG4326 - used by the W3C geolocation API)
|
||||
private_location extensions.GEOGRAPHY(POINT, 4326) NOT NULL DEFAULT public.get_latest_location(),
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Filter radius in meters (Clamped between 500 meters and 50 kilometers)
|
||||
radius DOUBLE PRECISION NOT NULL CHECK (500 <= radius AND radius <= 50000),
|
||||
|
||||
-- Plain-text content (Up to 300 characters)
|
||||
content VARCHAR(300) NOT NULL,
|
||||
|
||||
-- Whether or not the post has media (e.g.: an image or video)
|
||||
-- Note: media is stored in the `media` bucket with the name `posts/[Post ID]`, where `[Post ID]` refers to the `id` column of this table.
|
||||
-- Therefore, media can only be uploaded after a row is inserted into this table and its `id` column is retrieved.
|
||||
has_media BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
|
||||
-- Media blur hash (Up to 6 x 8 components)
|
||||
blur_hash VARCHAR(100) NULL,
|
||||
|
||||
-- Media aspect ratio (Used to prevent layout shifts)
|
||||
aspect_ratio DOUBLE PRECISION NULL,
|
||||
|
||||
-- View count
|
||||
views BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0),
|
||||
|
||||
-- Comment count
|
||||
comments BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0),
|
||||
|
||||
-- Upvote count
|
||||
upvotes BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0),
|
||||
|
||||
-- Downvote count
|
||||
downvotes BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0),
|
||||
|
||||
CHECK (
|
||||
(has_media AND blur_hash IS NOT NULL AND aspect_ratio IS NOT NULL) OR
|
||||
(NOT has_media AND blur_hash IS NULL AND aspect_ratio IS NULL)
|
||||
)
|
||||
);
|
||||
|
||||
-- Post views
|
||||
CREATE TABLE public.post_views (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Post ID (Foreign key to public.posts)
|
||||
post_id UUID NOT NULL REFERENCES public.posts ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Viewer user ID (Foreign key to auth.users)
|
||||
viewer_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Ensure the viewer can only view once per post
|
||||
UNIQUE (viewer_id, post_id)
|
||||
);
|
||||
|
||||
-- Post votes
|
||||
CREATE TABLE public.post_votes (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Voter user ID (Foreign key to auth.users)
|
||||
voter_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Post ID (Foreign key to public.posts)
|
||||
post_id UUID NOT NULL REFERENCES public.posts ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Whether the vote is an upvote (true) or a downvote (false)
|
||||
upvote BOOLEAN NOT NULL,
|
||||
|
||||
-- Ensure the voter can only vote once per post
|
||||
UNIQUE (voter_id, post_id)
|
||||
);
|
||||
|
||||
-- Post reports
|
||||
CREATE TABLE public.post_reports (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Reporter user ID (Foreign key to auth.users)
|
||||
reporter_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Post ID (Foreign key to public.posts)
|
||||
post_id UUID NOT NULL REFERENCES public.posts ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Ensure the reporter can only report once per post
|
||||
UNIQUE (reporter_id, post_id)
|
||||
);
|
||||
|
||||
-- Comments (Nestable)
|
||||
CREATE TABLE public.comments (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Private commenter user ID (Foreign key to auth.users)
|
||||
private_commenter_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Whether or not the comment is anonymous
|
||||
private_anonymous BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
|
||||
-- Public commenter ID (Only show if the comment is not anonymous)
|
||||
commenter_id UUID NULL GENERATED ALWAYS AS (
|
||||
CASE WHEN private_anonymous THEN NULL ELSE private_commenter_id END
|
||||
) STORED,
|
||||
|
||||
-- Parent post ID (Foreign key to public.posts)
|
||||
post_id UUID NOT NULL REFERENCES public.posts ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Parent comment ID (Foreign key to public.comments)
|
||||
parent_id UUID NULL REFERENCES public.comments ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Comment content (Up to 1000 characters)
|
||||
content VARCHAR(1000) NOT NULL,
|
||||
|
||||
-- View count
|
||||
views BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0),
|
||||
|
||||
-- Upvote count
|
||||
upvotes BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0),
|
||||
|
||||
-- Downvote count
|
||||
downvotes BIGINT NOT NULL DEFAULT 0 CHECK (views >= 0)
|
||||
);
|
||||
|
||||
-- Comment view
|
||||
CREATE TABLE public.comment_views (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Comment ID (Foreign key to public.comments)
|
||||
comment_id UUID NOT NULL REFERENCES public.comments ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Viewer user ID (Foreign key to auth.users)
|
||||
viewer_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Ensure the viewer can only view once per comment
|
||||
UNIQUE (viewer_id, comment_id)
|
||||
);
|
||||
|
||||
-- Comment votes
|
||||
CREATE TABLE public.comment_votes (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Voter user ID (Foreign key to auth.users)
|
||||
voter_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Comment ID (Foreign key to public.comments)
|
||||
comment_id UUID NOT NULL REFERENCES public.comments ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Whether the vote is an upvote (true) or a downvote (false)
|
||||
upvote BOOLEAN NOT NULL,
|
||||
|
||||
-- Ensure the voter can only vote once per comment
|
||||
UNIQUE (voter_id, comment_id)
|
||||
);
|
||||
|
||||
-- Comment reports
|
||||
CREATE TABLE public.comment_reports (
|
||||
-- Primary key
|
||||
id UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
|
||||
-- Reporter user ID (Foreign key to auth.users)
|
||||
reporter_id UUID NOT NULL REFERENCES auth.users ON UPDATE CASCADE ON DELETE CASCADE DEFAULT auth.uid(),
|
||||
|
||||
-- Comment ID (Foreign key to public.comments)
|
||||
comment_id UUID NOT NULL REFERENCES public.comments ON UPDATE CASCADE ON DELETE CASCADE,
|
||||
|
||||
-- Creation timestamp
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() CHECK (created_at <= NOW()),
|
||||
|
||||
-- Ensure the reporter can only report once per comment
|
||||
UNIQUE (reporter_id, comment_id)
|
||||
);
|
@@ -0,0 +1,124 @@
|
||||
/**
|
||||
* Setup views
|
||||
*/
|
||||
|
||||
/* ---------------------------------------- Setup views ---------------------------------------- */
|
||||
|
||||
-- Posts with additional, user-specific information
|
||||
CREATE VIEW public.personalized_posts
|
||||
WITH (
|
||||
security_barrier = TRUE,
|
||||
security_invoker = FALSE
|
||||
)
|
||||
AS (
|
||||
WITH personalized_post AS (
|
||||
SELECT
|
||||
post.id,
|
||||
post.private_poster_id,
|
||||
post.poster_id,
|
||||
post.created_at,
|
||||
post.radius,
|
||||
post.content,
|
||||
post.has_media,
|
||||
post.blur_hash,
|
||||
post.aspect_ratio,
|
||||
post.views,
|
||||
post.upvotes,
|
||||
post.downvotes,
|
||||
post.comments,
|
||||
public.distance_to(post.private_location) AS distance,
|
||||
|
||||
profile.color AS poster_color,
|
||||
profile.emoji AS poster_emoji,
|
||||
|
||||
vote.upvote
|
||||
FROM public.posts post
|
||||
LEFT JOIN public.profiles profile ON profile.id = post.poster_id
|
||||
LEFT JOIN public.post_votes vote ON vote.post_id = post.id AND vote.voter_id = auth.uid()
|
||||
)
|
||||
SELECT
|
||||
id,
|
||||
poster_id,
|
||||
created_at,
|
||||
content,
|
||||
has_media,
|
||||
blur_hash,
|
||||
aspect_ratio,
|
||||
views,
|
||||
upvotes,
|
||||
downvotes,
|
||||
comments,
|
||||
distance,
|
||||
public.calculate_rank(distance, upvotes - downvotes, created_at) AS rank,
|
||||
|
||||
private_poster_id = auth.uid() AS is_mine,
|
||||
poster_color,
|
||||
poster_emoji,
|
||||
|
||||
upvote
|
||||
FROM personalized_post
|
||||
-- This view doesn't have RLS, so we need to filter out posts the user can't see
|
||||
WHERE (
|
||||
-- Only select posts for which the user is the poster
|
||||
personalized_post.private_poster_id = auth.uid()
|
||||
|
||||
-- Or only select posts for which the user is within the post's radius
|
||||
OR personalized_post.distance <= personalized_post.radius
|
||||
)
|
||||
);
|
||||
|
||||
-- Comments with additional, user-specific information
|
||||
CREATE VIEW public.personalized_comments
|
||||
WITH (
|
||||
security_barrier = TRUE,
|
||||
security_invoker = FALSE
|
||||
)
|
||||
AS (
|
||||
WITH personalized_comment AS (
|
||||
SELECT
|
||||
comment.id,
|
||||
comment.private_commenter_id,
|
||||
comment.commenter_id,
|
||||
comment.post_id,
|
||||
comment.parent_id,
|
||||
comment.created_at,
|
||||
comment.content,
|
||||
comment.views,
|
||||
comment.upvotes,
|
||||
comment.downvotes,
|
||||
|
||||
profile.color AS commenter_color,
|
||||
profile.emoji AS commenter_emoji,
|
||||
|
||||
vote.upvote
|
||||
FROM public.comments comment
|
||||
LEFT JOIN public.profiles profile ON profile.id = comment.commenter_id
|
||||
LEFT JOIN public.comment_votes vote ON vote.comment_id = comment.id AND vote.voter_id = auth.uid()
|
||||
)
|
||||
SELECT
|
||||
id,
|
||||
commenter_id,
|
||||
post_id,
|
||||
parent_id,
|
||||
created_at,
|
||||
content,
|
||||
views,
|
||||
upvotes,
|
||||
downvotes,
|
||||
public.calculate_rank(0, upvotes - downvotes, created_at) AS rank,
|
||||
|
||||
private_commenter_id = auth.uid() AS is_mine,
|
||||
commenter_color,
|
||||
commenter_emoji,
|
||||
|
||||
upvote
|
||||
FROM personalized_comment
|
||||
-- This view doesn't have RLS, so we need to filter out comments the user can't see
|
||||
WHERE (
|
||||
-- Only get comments for which the user is the commenter
|
||||
personalized_comment.private_commenter_id = auth.uid()
|
||||
|
||||
-- Or only show comments for posts the user has access to
|
||||
OR public.validate_post_access(post_id)
|
||||
)
|
||||
);
|
@@ -0,0 +1,40 @@
|
||||
/**
|
||||
* Setup indexes
|
||||
*/
|
||||
|
||||
/* ---------------------------------------- Setup indexes --------------------------------------- */
|
||||
|
||||
-- User locations
|
||||
CREATE INDEX locations_user_id ON public.locations (user_id);
|
||||
|
||||
-- Posts
|
||||
CREATE INDEX posts_private_poster_id ON public.posts (private_poster_id);
|
||||
|
||||
-- Post views
|
||||
CREATE INDEX post_views_post_id ON public.post_views (post_id);
|
||||
CREATE INDEX post_views_viewer_id ON public.post_views (viewer_id);
|
||||
|
||||
-- Post votes
|
||||
CREATE INDEX post_votes_voter_id ON public.post_votes (voter_id);
|
||||
CREATE INDEX post_votes_post_id ON public.post_votes (post_id);
|
||||
|
||||
-- Post reports
|
||||
CREATE INDEX post_reports_reporter_id ON public.post_reports (reporter_id);
|
||||
CREATE INDEX post_reports_post_id ON public.post_reports (post_id);
|
||||
|
||||
-- Comments
|
||||
CREATE INDEX comments_private_commenter_id ON public.comments (private_commenter_id);
|
||||
CREATE INDEX comments_post_id ON public.comments (post_id);
|
||||
CREATE INDEX comments_parent_id ON public.comments (parent_id);
|
||||
|
||||
-- Comment views
|
||||
CREATE INDEX comment_views_comment_id ON public.comment_views (comment_id);
|
||||
CREATE INDEX comment_views_viewer_id ON public.comment_views (viewer_id);
|
||||
|
||||
-- Comment votes
|
||||
CREATE INDEX comment_votes_voter_id ON public.comment_votes (voter_id);
|
||||
CREATE INDEX comment_votes_comment_id ON public.comment_votes (comment_id);
|
||||
|
||||
-- Comment reports
|
||||
CREATE INDEX comment_reports_reporter_id ON public.comment_reports (reporter_id);
|
||||
CREATE INDEX comment_reports_comment_id ON public.comment_reports (comment_id);
|
@@ -0,0 +1,406 @@
|
||||
/**
|
||||
* Setup security policies
|
||||
*/
|
||||
|
||||
/* -------------------------------------- Reset privileges ------------------------------------- */
|
||||
|
||||
-- Alter default privileges
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA extensions REVOKE ALL ON SEQUENCES FROM anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA utilities REVOKE ALL ON SEQUENCES FROM anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA public REVOKE ALL ON SEQUENCES FROM anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA storage REVOKE ALL ON SEQUENCES FROM anon, authenticated;
|
||||
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA extensions REVOKE ALL ON TABLES FROM anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA utilities REVOKE ALL ON TABLES FROM anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA public REVOKE ALL ON TABLES FROM anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA storage REVOKE ALL ON TABLES FROM anon, authenticated;
|
||||
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA extensions REVOKE ALL ON ROUTINES FROM public, anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA utilities REVOKE ALL ON ROUTINES FROM public, anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA public REVOKE ALL ON ROUTINES FROM public, anon, authenticated;
|
||||
ALTER DEFAULT PRIVILEGES IN SCHEMA storage REVOKE ALL ON ROUTINES FROM public, anon, authenticated;
|
||||
|
||||
-- Revoke existing privileges
|
||||
REVOKE ALL PRIVILEGES ON DATABASE postgres FROM anon, authenticated;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON SCHEMA extensions FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON SCHEMA utilities FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON SCHEMA public FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON SCHEMA storage FROM anon, authenticated;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA extensions FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA utilities FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA storage FROM anon, authenticated;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA extensions FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA utilities FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA public FROM anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA storage FROM anon, authenticated;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON ALL ROUTINES IN SCHEMA extensions FROM public, anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL ROUTINES IN SCHEMA utilities FROM public, anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL ROUTINES IN SCHEMA public FROM public, anon, authenticated;
|
||||
REVOKE ALL PRIVILEGES ON ALL ROUTINES IN SCHEMA storage FROM public, anon, authenticated;
|
||||
|
||||
/* ----------------------------------- Setup type privileges ----------------------------------- */
|
||||
|
||||
-- Extensions
|
||||
GRANT USAGE ON SCHEMA extensions TO authenticated;
|
||||
|
||||
/* ---------------------------------- Setup routine privileges --------------------------------- */
|
||||
|
||||
-- Public routines
|
||||
GRANT EXECUTE ON FUNCTION public.validate_post_access(UUID) TO authenticated;
|
||||
GRANT EXECUTE ON FUNCTION public.validate_media_object_name(TEXT) TO authenticated;
|
||||
GRANT EXECUTE ON FUNCTION public.delete_account() TO authenticated;
|
||||
GRANT EXECUTE ON FUNCTION public.distance_to(extensions.GEOGRAPHY(POINT, 4326)) TO authenticated;
|
||||
GRANT EXECUTE ON FUNCTION public.get_latest_location() TO authenticated;
|
||||
GRANT EXECUTE ON FUNCTION public.calculate_rank(DOUBLE PRECISION, BIGINT, TIMESTAMPTZ) TO authenticated;
|
||||
|
||||
/* ----------------------------------- Setup view privileges ----------------------------------- */
|
||||
|
||||
-- Posts
|
||||
GRANT SELECT ON public.personalized_posts TO authenticated;
|
||||
|
||||
-- Comments
|
||||
GRANT SELECT ON public.personalized_comments TO authenticated;
|
||||
|
||||
/* ----------------------------------- Setup table privileges ---------------------------------- */
|
||||
|
||||
-- Profiles
|
||||
GRANT SELECT ON public.profiles TO authenticated;
|
||||
|
||||
-- User locations
|
||||
GRANT SELECT, DELETE ON public.locations TO authenticated;
|
||||
GRANT INSERT (
|
||||
location
|
||||
)
|
||||
ON public.locations TO authenticated;
|
||||
|
||||
-- Posts
|
||||
GRANT SELECT (id) ON public.posts TO authenticated;
|
||||
GRANT DELETE ON public.posts TO authenticated;
|
||||
GRANT INSERT (
|
||||
private_anonymous,
|
||||
radius,
|
||||
content,
|
||||
has_media,
|
||||
blur_hash,
|
||||
aspect_ratio
|
||||
)
|
||||
ON public.posts TO authenticated;
|
||||
|
||||
-- Post views
|
||||
GRANT SELECT, DELETE ON public.post_views TO authenticated;
|
||||
GRANT INSERT, UPDATE (
|
||||
post_id
|
||||
)
|
||||
ON public.post_views TO authenticated;
|
||||
|
||||
-- Post votes
|
||||
GRANT SELECT, DELETE ON public.post_votes TO authenticated;
|
||||
GRANT INSERT, UPDATE (
|
||||
post_id,
|
||||
upvote
|
||||
)
|
||||
ON public.post_votes TO authenticated;
|
||||
|
||||
-- Post reports
|
||||
GRANT SELECT, DELETE ON public.post_reports TO authenticated;
|
||||
GRANT INSERT (
|
||||
post_id
|
||||
)
|
||||
ON public.post_reports TO authenticated;
|
||||
|
||||
-- Comments
|
||||
GRANT SELECT (id) ON public.comments TO authenticated;
|
||||
GRANT DELETE ON public.comments TO authenticated;
|
||||
GRANT INSERT (
|
||||
private_anonymous,
|
||||
post_id,
|
||||
parent_id,
|
||||
content
|
||||
)
|
||||
ON public.comments TO authenticated;
|
||||
|
||||
-- Comment views
|
||||
GRANT SELECT, DELETE ON public.comment_views TO authenticated;
|
||||
GRANT INSERT, UPDATE (
|
||||
comment_id
|
||||
)
|
||||
ON public.comment_views TO authenticated;
|
||||
|
||||
-- Comment votes
|
||||
GRANT SELECT, DELETE ON public.comment_votes TO authenticated;
|
||||
GRANT INSERT, UPDATE (
|
||||
comment_id,
|
||||
upvote
|
||||
)
|
||||
ON public.comment_votes TO authenticated;
|
||||
|
||||
-- Comment reports
|
||||
GRANT SELECT, DELETE ON public.comment_reports TO authenticated;
|
||||
GRANT INSERT (
|
||||
comment_id
|
||||
)
|
||||
ON public.comment_reports TO authenticated;
|
||||
|
||||
/* -------------------------- Setup Row-level security (RLS) policies -------------------------- */
|
||||
|
||||
-- Enable row-level security
|
||||
ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.locations ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.posts ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.post_views ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.post_votes ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.post_reports ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.comments ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.comment_views ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.comment_votes ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.comment_reports ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Profiles
|
||||
CREATE POLICY select_profiles
|
||||
ON public.profiles
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (true);
|
||||
|
||||
-- User locations
|
||||
CREATE POLICY select_locations
|
||||
ON public.locations
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (user_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_locations
|
||||
ON public.locations
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (user_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_locations
|
||||
ON public.locations
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (user_id = (SELECT auth.uid()));
|
||||
|
||||
-- Posts
|
||||
CREATE POLICY select_posts
|
||||
ON public.posts
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (
|
||||
-- Only get posts for which the user is the poster
|
||||
private_poster_id = (SELECT auth.uid())
|
||||
|
||||
-- Or only get posts for which the user is within the post's radius
|
||||
OR public.distance_to(private_location) <= radius
|
||||
);
|
||||
|
||||
CREATE POLICY insert_posts
|
||||
ON public.posts
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (private_poster_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_posts
|
||||
ON public.posts
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (private_poster_id = (SELECT auth.uid()));
|
||||
|
||||
-- Post views
|
||||
CREATE POLICY select_post_views
|
||||
ON public.post_views
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_post_views
|
||||
ON public.post_views
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY update_post_views
|
||||
ON public.post_views
|
||||
FOR UPDATE
|
||||
TO authenticated
|
||||
USING (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_post_views
|
||||
ON public.post_views
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
-- Post votes
|
||||
CREATE POLICY select_post_votes
|
||||
ON public.post_votes
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (voter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_post_votes
|
||||
ON public.post_votes
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (voter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY update_post_votes
|
||||
ON public.post_votes
|
||||
FOR UPDATE
|
||||
TO authenticated
|
||||
USING (voter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_post_votes
|
||||
ON public.post_votes
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (voter_id = (SELECT auth.uid()));
|
||||
|
||||
-- Post reports
|
||||
CREATE POLICY select_post_reports
|
||||
ON public.post_reports
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (reporter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_post_reports
|
||||
ON public.post_reports
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (reporter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_post_reports
|
||||
ON public.post_reports
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (reporter_id = (SELECT auth.uid()));
|
||||
|
||||
-- Comments
|
||||
CREATE POLICY select_comments
|
||||
ON public.comments
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (
|
||||
-- Only get comments for which the user is the commenter
|
||||
private_commenter_id = (SELECT auth.uid())
|
||||
|
||||
-- Or only show comments for posts the user has access to
|
||||
OR public.validate_post_access(post_id)
|
||||
);
|
||||
|
||||
CREATE POLICY insert_comments
|
||||
ON public.comments
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (private_commenter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_comments
|
||||
ON public.comments
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (private_commenter_id = (SELECT auth.uid()));
|
||||
|
||||
-- Comment views
|
||||
CREATE POLICY select_comment_views
|
||||
ON public.comment_views
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_comment_views
|
||||
ON public.comment_views
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY update_comment_views
|
||||
ON public.comment_views
|
||||
FOR UPDATE
|
||||
TO authenticated
|
||||
USING (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_comment_views
|
||||
ON public.comment_views
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (viewer_id = (SELECT auth.uid()));
|
||||
|
||||
-- Comment votes
|
||||
CREATE POLICY select_comment_votes
|
||||
ON public.comment_votes
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (voter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_comment_votes
|
||||
ON public.comment_votes
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (voter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY update_comment_votes
|
||||
ON public.comment_votes
|
||||
FOR UPDATE
|
||||
TO authenticated
|
||||
USING (voter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_comment_votes
|
||||
ON public.comment_votes
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (voter_id = (SELECT auth.uid()));
|
||||
|
||||
-- Comment reports
|
||||
CREATE POLICY select_comment_reports
|
||||
ON public.comment_reports
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (reporter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY insert_comment_reports
|
||||
ON public.comment_reports
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (reporter_id = (SELECT auth.uid()));
|
||||
|
||||
CREATE POLICY delete_comment_reports
|
||||
ON public.comment_reports
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (reporter_id = (SELECT auth.uid()));
|
||||
|
||||
-- Media
|
||||
CREATE POLICY select_media_objects
|
||||
ON storage.objects
|
||||
FOR SELECT
|
||||
TO authenticated
|
||||
USING (bucket_id = 'media');
|
||||
|
||||
CREATE POLICY insert_media_objects
|
||||
ON storage.objects
|
||||
FOR INSERT
|
||||
TO authenticated
|
||||
WITH CHECK (
|
||||
-- Media bucket
|
||||
bucket_id = 'media'
|
||||
|
||||
-- Valiate the object name
|
||||
AND public.validate_media_object_name(name)
|
||||
);
|
||||
|
||||
CREATE POLICY delete_media_objects
|
||||
ON storage.objects
|
||||
FOR DELETE
|
||||
TO authenticated
|
||||
USING (
|
||||
-- Media bucket
|
||||
bucket_id = 'media'
|
||||
|
||||
-- Valiate the object name
|
||||
AND public.validate_media_object_name(name)
|
||||
);
|
@@ -0,0 +1,115 @@
|
||||
/**
|
||||
* Setup triggers
|
||||
*/
|
||||
|
||||
/* --------------------------------------- Setup triggers -------------------------------------- */
|
||||
|
||||
-- Create a profile for a new user
|
||||
CREATE TRIGGER create_profile_after_insert
|
||||
AFTER INSERT ON auth.users
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.setup_profile_trigger();
|
||||
|
||||
-- Validate new locations
|
||||
CREATE TRIGGER validate_location_before_insert
|
||||
BEFORE INSERT ON public.locations
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.validate_location_trigger();
|
||||
|
||||
-- Prune old locations
|
||||
CREATE TRIGGER prune_locations_after_insert
|
||||
AFTER INSERT ON public.locations
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.prune_locations_trigger();
|
||||
|
||||
-- Anonymize the location of a new post
|
||||
CREATE TRIGGER anonymize_post_location_before_insert
|
||||
BEFORE INSERT ON public.posts
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.anonymize_location_trigger();
|
||||
|
||||
-- Post deleted
|
||||
CREATE TRIGGER post_deleted_after_delete
|
||||
AFTER DELETE ON public.posts
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_deleted_trigger();
|
||||
|
||||
-- Post view modified
|
||||
CREATE TRIGGER post_view_modified_after_insert
|
||||
AFTER INSERT ON public.post_views
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_view_modified_trigger();
|
||||
|
||||
CREATE TRIGGER post_view_modified_after_update
|
||||
AFTER UPDATE ON public.post_views
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_view_modified_trigger();
|
||||
|
||||
CREATE TRIGGER post_view_modified_after_delete
|
||||
AFTER DELETE ON public.post_views
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_view_modified_trigger();
|
||||
|
||||
-- Post vote modified
|
||||
CREATE TRIGGER post_vote_modified_after_insert
|
||||
AFTER INSERT ON public.post_votes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_vote_modified_trigger();
|
||||
|
||||
CREATE TRIGGER post_vote_modified_after_update
|
||||
AFTER UPDATE ON public.post_votes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_vote_modified_trigger();
|
||||
|
||||
CREATE TRIGGER post_vote_modified_after_delete
|
||||
AFTER DELETE ON public.post_votes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.post_vote_modified_trigger();
|
||||
|
||||
-- Comment modified
|
||||
CREATE TRIGGER comment_modified_after_insert
|
||||
AFTER INSERT ON public.comments
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_modified_trigger();
|
||||
|
||||
CREATE TRIGGER comment_modified_after_update
|
||||
AFTER UPDATE ON public.comments
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_modified_trigger();
|
||||
|
||||
CREATE TRIGGER comment_modified_after_delete
|
||||
AFTER DELETE ON public.comments
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_modified_trigger();
|
||||
|
||||
-- Comment view modified
|
||||
CREATE TRIGGER comment_view_modified_after_insert
|
||||
AFTER INSERT ON public.comment_views
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_view_modified_trigger();
|
||||
|
||||
CREATE TRIGGER comment_view_modified_after_update
|
||||
AFTER UPDATE ON public.comment_views
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_view_modified_trigger();
|
||||
|
||||
CREATE TRIGGER comment_view_modified_after_delete
|
||||
AFTER DELETE ON public.comment_views
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_view_modified_trigger();
|
||||
|
||||
-- Comment vote modified
|
||||
CREATE TRIGGER comment_vote_modified_after_insert
|
||||
AFTER INSERT ON public.comment_votes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_vote_modified_trigger();
|
||||
|
||||
CREATE TRIGGER comment_vote_modified_after_update
|
||||
AFTER UPDATE ON public.comment_votes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_vote_modified_trigger();
|
||||
|
||||
CREATE TRIGGER comment_vote_modified_after_delete
|
||||
AFTER DELETE ON public.comment_votes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION utilities.comment_vote_modified_trigger();
|
@@ -0,0 +1,12 @@
|
||||
/**
|
||||
* Setup miscellaneous things after the main setup
|
||||
*/
|
||||
|
||||
/* -------------------------------------- Setup cron jobs -------------------------------------- */
|
||||
|
||||
-- Prune expired locations
|
||||
SELECT cron.schedule(
|
||||
'hourly-location-cleanup',
|
||||
'0 * * * *',
|
||||
'SELECT utilities.prune_expired_locations()'
|
||||
);
|
213
99_references/beacon-main/supabase/supabase.ts
Normal file
213
99_references/beacon-main/supabase/supabase.ts
Normal file
@@ -0,0 +1,213 @@
|
||||
/* eslint-disable unicorn/no-process-exit */
|
||||
/**
|
||||
* @file Programmatic local Supabase instance management
|
||||
*/
|
||||
|
||||
import {dirname, join} from "node:path";
|
||||
import {fileURLToPath} from "node:url";
|
||||
|
||||
import {execa} from "execa";
|
||||
|
||||
/**
|
||||
* Instance status
|
||||
*/
|
||||
export interface InstanceStatus {
|
||||
/**
|
||||
* API URL
|
||||
*/
|
||||
apiUrl: string;
|
||||
|
||||
/**
|
||||
* GraphQL URL
|
||||
*/
|
||||
graphUrl: string;
|
||||
|
||||
/**
|
||||
* Database URL
|
||||
*/
|
||||
dbUrl: string;
|
||||
|
||||
/**
|
||||
* Studio GUI URL
|
||||
*/
|
||||
studioUrl: string;
|
||||
|
||||
/**
|
||||
* Inbucket API URL
|
||||
*/
|
||||
inbucketUrl: string;
|
||||
|
||||
/**
|
||||
* JWT secret
|
||||
*/
|
||||
jwtSecret: string;
|
||||
|
||||
/**
|
||||
* Anonymous API key
|
||||
*/
|
||||
anonKey: string;
|
||||
|
||||
/**
|
||||
* Service role API key
|
||||
*/
|
||||
serviceRoleKey: string;
|
||||
}
|
||||
|
||||
/**
|
||||
* Project root directory
|
||||
*/
|
||||
export const root = join(dirname(fileURLToPath(import.meta.url)), "..");
|
||||
|
||||
/**
|
||||
* Start local Supabase instance
|
||||
*/
|
||||
export const start = async () => {
|
||||
const {all, exitCode, failed} = await execa(
|
||||
"supabase",
|
||||
[
|
||||
"start",
|
||||
"--debug",
|
||||
],
|
||||
{
|
||||
all: true,
|
||||
cwd: root,
|
||||
preferLocal: true,
|
||||
reject: false,
|
||||
},
|
||||
);
|
||||
|
||||
if (failed) {
|
||||
console.error(`Starting Supabase failed (Exit code ${exitCode}): ${all}`);
|
||||
process.exit(1);
|
||||
}
|
||||
};
|
||||
|
||||
/**
|
||||
* Reset local Supabase instance
|
||||
*/
|
||||
export const reset = async () => {
|
||||
const {all, exitCode, failed} = await execa(
|
||||
"supabase",
|
||||
[
|
||||
"db",
|
||||
"reset",
|
||||
"--debug",
|
||||
],
|
||||
{
|
||||
all: true,
|
||||
cwd: root,
|
||||
preferLocal: true,
|
||||
reject: false,
|
||||
},
|
||||
);
|
||||
|
||||
console.log(`Output: ${all}`, failed);
|
||||
|
||||
if (failed) {
|
||||
console.error(`Resetting Supabase failed (Exit code ${exitCode}): ${all}`);
|
||||
process.exit(1);
|
||||
}
|
||||
};
|
||||
|
||||
/**
|
||||
* Get the status of the local Supabase instance
|
||||
* @returns Local Supabase instance status
|
||||
*/
|
||||
export const getStatus = async () => {
|
||||
// Get the raw status
|
||||
const {all, exitCode, failed, stdout} = await execa(
|
||||
"supabase",
|
||||
[
|
||||
"status",
|
||||
],
|
||||
{
|
||||
all: true,
|
||||
cwd: root,
|
||||
preferLocal: true,
|
||||
reject: false,
|
||||
},
|
||||
);
|
||||
|
||||
if (failed) {
|
||||
console.error(
|
||||
`Getting Supabase status failed (Exit code ${exitCode}): ${all}`,
|
||||
);
|
||||
|
||||
process.exit(1);
|
||||
}
|
||||
|
||||
// Parse the status
|
||||
const apiUrl = /API URL: (\S+)/.exec(stdout)?.[1];
|
||||
const graphUrl = /GraphQL URL: (\S+)/.exec(stdout)?.[1];
|
||||
const dbUrl = /DB URL: (\S+)/.exec(stdout)?.[1];
|
||||
const studioUrl = /Studio URL: (\S+)/.exec(stdout)?.[1];
|
||||
const inbucketUrl = /Inbucket URL: (\S+)/.exec(stdout)?.[1];
|
||||
const jwtSecret = /JWT secret: (\S+)/.exec(stdout)?.[1];
|
||||
const anonKey = /anon key: (\S+)/.exec(stdout)?.[1];
|
||||
const serviceRoleKey = /service_role key: (\S+)/.exec(stdout)?.[1];
|
||||
|
||||
if (
|
||||
apiUrl === undefined ||
|
||||
graphUrl === undefined ||
|
||||
dbUrl === undefined ||
|
||||
studioUrl === undefined ||
|
||||
inbucketUrl === undefined ||
|
||||
jwtSecret === undefined ||
|
||||
anonKey === undefined ||
|
||||
serviceRoleKey === undefined
|
||||
) {
|
||||
console.error(
|
||||
`Failed to extract Supabase status (Exit code ${exitCode}): ${all}`,
|
||||
);
|
||||
|
||||
process.exit(1);
|
||||
}
|
||||
|
||||
const status: InstanceStatus = {
|
||||
apiUrl,
|
||||
graphUrl,
|
||||
dbUrl,
|
||||
studioUrl,
|
||||
inbucketUrl,
|
||||
jwtSecret,
|
||||
anonKey,
|
||||
serviceRoleKey,
|
||||
};
|
||||
|
||||
return status;
|
||||
};
|
||||
|
||||
/**
|
||||
* Get the Supabase schema
|
||||
* @returns Supabase schema
|
||||
*/
|
||||
export const getSchema = async () => {
|
||||
// Generate the arguments
|
||||
const args = [
|
||||
"gen",
|
||||
"types",
|
||||
"typescript",
|
||||
"--local",
|
||||
"--schema",
|
||||
"public",
|
||||
"--debug",
|
||||
];
|
||||
|
||||
// Generate the schema
|
||||
const {all, exitCode, failed, stdout} = await execa("supabase", args, {
|
||||
all: true,
|
||||
cwd: root,
|
||||
preferLocal: true,
|
||||
reject: false,
|
||||
});
|
||||
|
||||
if (failed) {
|
||||
console.error(
|
||||
`Getting Supabase schema failed (Exit code ${exitCode}): ${all}`,
|
||||
);
|
||||
|
||||
process.exit(1);
|
||||
}
|
||||
|
||||
return stdout;
|
||||
};
|
234
99_references/beacon-main/supabase/tests/security.test.ts
Normal file
234
99_references/beacon-main/supabase/tests/security.test.ts
Normal file
@@ -0,0 +1,234 @@
|
||||
/* eslint-disable camelcase */
|
||||
/**
|
||||
* @file Database security tests
|
||||
*/
|
||||
|
||||
import {beforeAll, describe, expect, test} from "vitest";
|
||||
|
||||
import {reset} from "#/supabase/supabase";
|
||||
import {client} from "~/lib/supabase";
|
||||
|
||||
describe(
|
||||
"database security",
|
||||
{
|
||||
sequential: true,
|
||||
},
|
||||
() => {
|
||||
beforeAll(
|
||||
async () => {
|
||||
// Reset Supabase
|
||||
await reset();
|
||||
},
|
||||
1000 * 60 * 5,
|
||||
);
|
||||
|
||||
describe("unauthenticated user", () => {
|
||||
test.each([
|
||||
[
|
||||
"utilities",
|
||||
"safe_random",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"get_random_color",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"get_random_emoji",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"prune_expired_locations",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"prune_locations_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"setup_profile_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"validate_location_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"anonymize_location_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"post_deleted_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"post_view_modified_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"post_vote_modified_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"comment_modified_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"comment_view_modified_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"utilities",
|
||||
"comment_vote_modified_trigger",
|
||||
{},
|
||||
"The schema must be one of the following: public, storage, graphql_public",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"validate_post_access",
|
||||
{
|
||||
_post_id: "'00000000-0000-0000-0000-000000000000'::UUID",
|
||||
},
|
||||
"permission denied for function validate_post_access",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"validate_media_object_name",
|
||||
{
|
||||
_object_name: "",
|
||||
},
|
||||
"permission denied for function validate_media_object_name",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"delete_account",
|
||||
{},
|
||||
"permission denied for function delete_account",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"distance_to",
|
||||
{
|
||||
_other_location: "'POINT(0 0)'::extensions.GEOMETRY",
|
||||
},
|
||||
"permission denied for schema extensions",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"get_latest_location",
|
||||
{},
|
||||
"permission denied for function get_latest_location",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"calculate_rank",
|
||||
{
|
||||
_distance: 0,
|
||||
_score: 0,
|
||||
_created_at: "'1970-01-01T00:00:00Z'::TIMESTAMPTZ",
|
||||
},
|
||||
"permission denied for function calculate_rank",
|
||||
],
|
||||
])("can't call routine %s.%s", async (schema, fn, args, message) => {
|
||||
await expect(
|
||||
client.schema(schema as any).rpc(fn as any, args),
|
||||
).resolves.toHaveProperty("error.message", message);
|
||||
});
|
||||
|
||||
test.each([
|
||||
[
|
||||
"public",
|
||||
"profiles",
|
||||
"permission denied for table profiles",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"locations",
|
||||
"permission denied for table locations",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"posts",
|
||||
"permission denied for table posts",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"personalized_posts",
|
||||
"permission denied for view personalized_posts",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"post_views",
|
||||
"permission denied for table post_views",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"post_votes",
|
||||
"permission denied for table post_votes",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"post_reports",
|
||||
"permission denied for table post_reports",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"comments",
|
||||
"permission denied for table comments",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"personalized_comments",
|
||||
"permission denied for view personalized_comments",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"comment_views",
|
||||
"permission denied for table comment_views",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"comment_votes",
|
||||
"permission denied for table comment_votes",
|
||||
],
|
||||
[
|
||||
"public",
|
||||
"comment_reports",
|
||||
"permission denied for table comment_reports",
|
||||
],
|
||||
])("can't select relation %s.%s", async (schema, relation, message) => {
|
||||
await expect(
|
||||
client
|
||||
.schema(schema as any)
|
||||
.from(relation as any)
|
||||
.select("*"),
|
||||
).resolves.toHaveProperty("error.message", message);
|
||||
});
|
||||
});
|
||||
},
|
||||
);
|
Reference in New Issue
Block a user