mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:31:13 -05:00
Add documentation to files
This commit is contained in:
636
docs/DATABASE_ARCHITECTURE.md
Normal file
636
docs/DATABASE_ARCHITECTURE.md
Normal file
@@ -0,0 +1,636 @@
|
||||
# Database Architecture
|
||||
|
||||
Complete documentation of ThrillWiki's PostgreSQL database schema, Row-Level Security policies, and design patterns.
|
||||
|
||||
---
|
||||
|
||||
## Core Principles
|
||||
|
||||
1. **NO JSONB for relational data** - All data properly normalized
|
||||
2. **Metric-first storage** - All measurements in metric (km/h, m, cm, kg)
|
||||
3. **Relational versioning** - Full history without JSONB
|
||||
4. **RLS everywhere** - Row-Level Security on all tables
|
||||
5. **Moderation-first** - Direct writes blocked, all through approval flow
|
||||
|
||||
---
|
||||
|
||||
## Primary Entity Tables
|
||||
|
||||
### parks
|
||||
|
||||
Public-facing theme park/amusement park entities.
|
||||
|
||||
```sql
|
||||
CREATE TABLE parks (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT UNIQUE NOT NULL,
|
||||
description TEXT,
|
||||
park_type TEXT CHECK (park_type IN ('theme_park', 'amusement_park', 'water_park', 'family_entertainment_center')),
|
||||
status TEXT CHECK (status IN ('operating', 'closed', 'seasonal', 'construction')),
|
||||
|
||||
-- Dates with precision
|
||||
opening_date DATE,
|
||||
closing_date DATE,
|
||||
opening_date_precision TEXT CHECK (opening_date_precision IN ('day', 'month', 'year')),
|
||||
closing_date_precision TEXT CHECK (closing_date_precision IN ('day', 'month', 'year')),
|
||||
|
||||
-- Relations
|
||||
location_id UUID REFERENCES locations(id),
|
||||
operator_id UUID REFERENCES companies(id),
|
||||
property_owner_id UUID REFERENCES companies(id),
|
||||
|
||||
-- Contact
|
||||
website_url TEXT,
|
||||
phone TEXT,
|
||||
email TEXT,
|
||||
|
||||
-- Images (CloudFlare IDs)
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT,
|
||||
|
||||
-- Computed stats
|
||||
ride_count INTEGER DEFAULT 0,
|
||||
coaster_count INTEGER DEFAULT 0,
|
||||
average_rating NUMERIC(3,2),
|
||||
review_count INTEGER DEFAULT 0,
|
||||
|
||||
-- View tracking
|
||||
view_count_7d INTEGER DEFAULT 0,
|
||||
view_count_30d INTEGER DEFAULT 0,
|
||||
view_count_all INTEGER DEFAULT 0,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Public READ, direct INSERT/UPDATE blocked
|
||||
CREATE POLICY "Public read access" ON parks FOR SELECT USING (true);
|
||||
CREATE POLICY "Deny direct inserts" ON parks FOR INSERT WITH CHECK (false);
|
||||
CREATE POLICY "Deny direct updates" ON parks FOR UPDATE USING (false);
|
||||
```
|
||||
|
||||
### rides
|
||||
|
||||
Roller coasters, flat rides, water rides, dark rides, etc.
|
||||
|
||||
```sql
|
||||
CREATE TABLE rides (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT UNIQUE NOT NULL,
|
||||
description TEXT,
|
||||
category TEXT CHECK (category IN ('roller_coaster', 'flat_ride', 'water_ride', 'dark_ride', 'transport', 'show', 'other')),
|
||||
status TEXT CHECK (status IN ('operating', 'closed', 'sbno', 'relocated', 'demolished')),
|
||||
|
||||
-- Relations
|
||||
park_id UUID REFERENCES parks(id) NOT NULL,
|
||||
manufacturer_id UUID REFERENCES companies(id),
|
||||
designer_id UUID REFERENCES companies(id),
|
||||
ride_model_id UUID REFERENCES ride_models(id),
|
||||
|
||||
-- Dates with precision
|
||||
opening_date DATE,
|
||||
closing_date DATE,
|
||||
opening_date_precision TEXT,
|
||||
closing_date_precision TEXT,
|
||||
|
||||
-- Roller coaster stats (ALWAYS METRIC)
|
||||
max_speed_kmh NUMERIC(6,2),
|
||||
max_height_meters NUMERIC(6,2),
|
||||
length_meters NUMERIC(8,2),
|
||||
drop_height_meters NUMERIC(6,2),
|
||||
inversions INTEGER,
|
||||
max_g_force NUMERIC(4,2),
|
||||
duration_seconds INTEGER,
|
||||
capacity_per_hour INTEGER,
|
||||
height_requirement_cm NUMERIC(5,2),
|
||||
age_requirement INTEGER,
|
||||
|
||||
coaster_type TEXT,
|
||||
seating_type TEXT,
|
||||
intensity_level TEXT CHECK (intensity_level IN ('low', 'moderate', 'high', 'extreme')),
|
||||
|
||||
-- Images
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT,
|
||||
|
||||
-- Computed stats
|
||||
average_rating NUMERIC(3,2),
|
||||
review_count INTEGER DEFAULT 0,
|
||||
view_count_7d INTEGER DEFAULT 0,
|
||||
view_count_30d INTEGER DEFAULT 0,
|
||||
view_count_all INTEGER DEFAULT 0,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Public READ, direct writes blocked
|
||||
CREATE POLICY "Public read access" ON rides FOR SELECT USING (true);
|
||||
CREATE POLICY "Deny direct inserts" ON rides FOR INSERT WITH CHECK (false);
|
||||
CREATE POLICY "Deny direct updates" ON rides FOR UPDATE USING (false);
|
||||
```
|
||||
|
||||
### companies
|
||||
|
||||
Manufacturers, designers, operators, property owners.
|
||||
|
||||
```sql
|
||||
CREATE TABLE companies (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT UNIQUE NOT NULL,
|
||||
description TEXT,
|
||||
company_type TEXT CHECK (company_type IN ('manufacturer', 'designer', 'operator', 'property_owner')),
|
||||
person_type TEXT CHECK (person_type IN ('company', 'individual', 'firm', 'organization')),
|
||||
|
||||
founded_date DATE,
|
||||
founded_date_precision TEXT,
|
||||
founded_year INTEGER, -- Legacy, prefer founded_date
|
||||
|
||||
headquarters_location TEXT,
|
||||
website_url TEXT,
|
||||
|
||||
-- Images
|
||||
logo_url TEXT,
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT,
|
||||
|
||||
-- Computed stats
|
||||
average_rating NUMERIC(3,2),
|
||||
review_count INTEGER DEFAULT 0,
|
||||
view_count_7d INTEGER DEFAULT 0,
|
||||
view_count_30d INTEGER DEFAULT 0,
|
||||
view_count_all INTEGER DEFAULT 0,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Same as parks/rides
|
||||
```
|
||||
|
||||
### ride_models
|
||||
|
||||
Manufacturer's ride models (e.g., "Inverted Coaster", "Flying Coaster").
|
||||
|
||||
```sql
|
||||
CREATE TABLE ride_models (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT UNIQUE NOT NULL,
|
||||
manufacturer_id UUID REFERENCES companies(id) NOT NULL,
|
||||
category TEXT,
|
||||
ride_type TEXT,
|
||||
description TEXT,
|
||||
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Same as other entities
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Relational Data Tables (NO JSONB!)
|
||||
|
||||
### ride_coaster_stats
|
||||
|
||||
Normalized coaster statistics (replaces old JSONB column).
|
||||
|
||||
```sql
|
||||
CREATE TABLE ride_coaster_stats (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
ride_id UUID REFERENCES rides(id) NOT NULL,
|
||||
stat_name TEXT NOT NULL, -- 'max_speed', 'height', 'length', etc.
|
||||
stat_value NUMERIC NOT NULL, -- ALWAYS METRIC
|
||||
unit TEXT NOT NULL, -- 'km/h', 'm', 'cm', 'kg'
|
||||
category TEXT, -- Grouping for UI
|
||||
description TEXT,
|
||||
display_order INTEGER,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Public READ, moderators manage
|
||||
CREATE POLICY "Public read" ON ride_coaster_stats FOR SELECT USING (true);
|
||||
CREATE POLICY "Moderators manage" ON ride_coaster_stats FOR ALL
|
||||
USING (is_moderator(auth.uid()));
|
||||
```
|
||||
|
||||
### ride_technical_specifications
|
||||
|
||||
Normalized technical specs (track type, launch system, etc.).
|
||||
|
||||
```sql
|
||||
CREATE TABLE ride_technical_specifications (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
ride_id UUID REFERENCES rides(id) NOT NULL,
|
||||
spec_name TEXT NOT NULL,
|
||||
spec_value TEXT NOT NULL,
|
||||
spec_type TEXT CHECK (spec_type IN ('string', 'number', 'boolean', 'date')),
|
||||
category TEXT,
|
||||
unit TEXT,
|
||||
display_order INTEGER,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Same as ride_coaster_stats
|
||||
```
|
||||
|
||||
### locations
|
||||
|
||||
Geographic locations for parks.
|
||||
|
||||
```sql
|
||||
CREATE TABLE locations (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT,
|
||||
country TEXT NOT NULL,
|
||||
state_province TEXT,
|
||||
city TEXT,
|
||||
postal_code TEXT,
|
||||
latitude NUMERIC(10,7),
|
||||
longitude NUMERIC(10,7),
|
||||
timezone TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Public READ, moderators INSERT/UPDATE
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## User & Profile Tables
|
||||
|
||||
### profiles
|
||||
|
||||
Public-facing user data (privacy-filtered).
|
||||
|
||||
```sql
|
||||
CREATE TABLE profiles (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES auth.users(id) UNIQUE NOT NULL,
|
||||
username TEXT UNIQUE NOT NULL,
|
||||
display_name TEXT,
|
||||
bio TEXT,
|
||||
avatar_url TEXT,
|
||||
avatar_image_id TEXT,
|
||||
|
||||
-- Privacy
|
||||
preferred_pronouns TEXT,
|
||||
show_pronouns BOOLEAN DEFAULT false,
|
||||
privacy_level TEXT CHECK (privacy_level IN ('public', 'friends', 'private')) DEFAULT 'public',
|
||||
|
||||
-- Preferences
|
||||
timezone TEXT,
|
||||
preferred_language TEXT,
|
||||
theme_preference TEXT CHECK (theme_preference IN ('light', 'dark', 'system')) DEFAULT 'system',
|
||||
|
||||
-- Location
|
||||
location_id UUID REFERENCES locations(id),
|
||||
personal_location TEXT, -- User-entered
|
||||
home_park_id UUID REFERENCES parks(id),
|
||||
|
||||
date_of_birth DATE,
|
||||
|
||||
-- Stats
|
||||
ride_count INTEGER DEFAULT 0,
|
||||
coaster_count INTEGER DEFAULT 0,
|
||||
park_count INTEGER DEFAULT 0,
|
||||
review_count INTEGER DEFAULT 0,
|
||||
reputation_score INTEGER DEFAULT 0,
|
||||
|
||||
-- Moderation
|
||||
banned BOOLEAN DEFAULT false,
|
||||
deactivated BOOLEAN DEFAULT false,
|
||||
deactivated_at TIMESTAMPTZ,
|
||||
deactivation_reason TEXT,
|
||||
|
||||
oauth_provider TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Privacy-filtered via get_filtered_profile() function
|
||||
CREATE POLICY "Privacy filtered" ON profiles FOR SELECT
|
||||
USING (get_filtered_profile(user_id, auth.uid()) IS NOT NULL);
|
||||
```
|
||||
|
||||
### user_roles
|
||||
|
||||
Role-based access control (ONE role per user).
|
||||
|
||||
```sql
|
||||
CREATE TYPE app_role AS ENUM ('user', 'moderator', 'admin', 'superuser');
|
||||
|
||||
CREATE TABLE user_roles (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES auth.users(id) UNIQUE NOT NULL,
|
||||
role app_role NOT NULL DEFAULT 'user',
|
||||
granted_by UUID REFERENCES auth.users(id),
|
||||
granted_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Moderators+ can read, admins+ can write (with MFA)
|
||||
CREATE POLICY "Moderators read" ON user_roles FOR SELECT
|
||||
USING (is_moderator(auth.uid()));
|
||||
|
||||
CREATE POLICY "Admins write" ON user_roles FOR ALL
|
||||
USING (is_admin(auth.uid()) AND (NOT has_mfa_enabled(auth.uid()) OR has_aal2()));
|
||||
```
|
||||
|
||||
### user_ride_credits
|
||||
|
||||
User's tracked rides.
|
||||
|
||||
```sql
|
||||
CREATE TABLE user_ride_credits (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES auth.users(id) NOT NULL,
|
||||
ride_id UUID REFERENCES rides(id) NOT NULL,
|
||||
first_ride_date DATE,
|
||||
last_ride_date DATE,
|
||||
ride_count INTEGER DEFAULT 1,
|
||||
sort_order INTEGER, -- For drag-drop sorting
|
||||
personal_notes TEXT,
|
||||
personal_rating NUMERIC(2,1) CHECK (personal_rating >= 1 AND personal_rating <= 5),
|
||||
personal_photo_id TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
|
||||
UNIQUE(user_id, ride_id)
|
||||
);
|
||||
|
||||
-- RLS: Users manage own credits
|
||||
CREATE POLICY "Users manage own" ON user_ride_credits FOR ALL
|
||||
USING (auth.uid() = user_id);
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Moderation System Tables
|
||||
|
||||
### content_submissions
|
||||
|
||||
Main moderation queue.
|
||||
|
||||
```sql
|
||||
CREATE TABLE content_submissions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES auth.users(id), -- Nullable after anonymization
|
||||
submission_type TEXT CHECK (submission_type IN ('park', 'ride', 'company', 'ride_model', 'photo')),
|
||||
|
||||
-- MINIMAL metadata only (NOT full form data!)
|
||||
content JSONB NOT NULL,
|
||||
|
||||
status TEXT CHECK (status IN ('pending', 'partially_approved', 'approved', 'rejected')) DEFAULT 'pending',
|
||||
approval_mode TEXT CHECK (approval_mode IN ('full', 'selective')) DEFAULT 'full',
|
||||
|
||||
reviewer_id UUID REFERENCES auth.users(id),
|
||||
reviewer_notes TEXT,
|
||||
|
||||
submitted_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
reviewed_at TIMESTAMPTZ,
|
||||
resolved_at TIMESTAMPTZ,
|
||||
|
||||
-- Lock management (15-minute locks)
|
||||
assigned_to UUID REFERENCES auth.users(id),
|
||||
assigned_at TIMESTAMPTZ,
|
||||
locked_until TIMESTAMPTZ,
|
||||
review_count INTEGER DEFAULT 0,
|
||||
first_reviewed_at TIMESTAMPTZ,
|
||||
|
||||
-- Escalation
|
||||
escalated BOOLEAN DEFAULT false,
|
||||
escalated_by UUID REFERENCES auth.users(id),
|
||||
escalated_at TIMESTAMPTZ,
|
||||
escalation_reason TEXT,
|
||||
|
||||
original_submission_id UUID REFERENCES content_submissions(id),
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Users see own, moderators see all (with AAL2 if MFA enrolled)
|
||||
CREATE POLICY "Users see own" ON content_submissions FOR SELECT
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Moderators see all" ON content_submissions FOR SELECT
|
||||
USING (is_moderator(auth.uid()) AND (NOT has_mfa_enabled(auth.uid()) OR has_aal2()));
|
||||
```
|
||||
|
||||
### submission_items
|
||||
|
||||
Actual submission data (normalized).
|
||||
|
||||
```sql
|
||||
CREATE TABLE submission_items (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
submission_id UUID REFERENCES content_submissions(id) NOT NULL,
|
||||
item_type TEXT NOT NULL,
|
||||
action_type TEXT CHECK (action_type IN ('create', 'edit', 'delete')) NOT NULL,
|
||||
|
||||
item_data JSONB NOT NULL, -- NEW data for this item
|
||||
original_data JSONB, -- OLD data for edits
|
||||
|
||||
status TEXT CHECK (status IN ('pending', 'approved', 'rejected')) DEFAULT 'pending',
|
||||
order_index INTEGER NOT NULL,
|
||||
depends_on UUID REFERENCES submission_items(id), -- Dependency chain
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- RLS: Same as content_submissions
|
||||
```
|
||||
|
||||
### photo_submissions & photo_submission_items
|
||||
|
||||
Special handling for photo uploads.
|
||||
|
||||
```sql
|
||||
CREATE TABLE photo_submissions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
submission_id UUID REFERENCES content_submissions(id) NOT NULL,
|
||||
entity_type TEXT NOT NULL,
|
||||
entity_id UUID NOT NULL,
|
||||
parent_id UUID, -- Optional grouping
|
||||
title TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE photo_submission_items (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
photo_submission_id UUID REFERENCES photo_submissions(id) NOT NULL,
|
||||
cloudflare_image_id TEXT NOT NULL,
|
||||
cloudflare_image_url TEXT NOT NULL,
|
||||
title TEXT,
|
||||
caption TEXT,
|
||||
date_taken DATE,
|
||||
date_taken_precision TEXT,
|
||||
filename TEXT,
|
||||
mime_type TEXT,
|
||||
file_size BIGINT,
|
||||
order_index INTEGER,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Versioning System Tables
|
||||
|
||||
Each entity has a corresponding `_versions` table with full relational data.
|
||||
|
||||
### park_versions (example)
|
||||
|
||||
```sql
|
||||
CREATE TABLE park_versions (
|
||||
version_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
park_id UUID REFERENCES parks(id) NOT NULL,
|
||||
version_number INTEGER NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
created_by UUID REFERENCES auth.users(id),
|
||||
change_type version_change_type CHECK (change_type IN ('created', 'updated', 'deleted')),
|
||||
change_reason TEXT,
|
||||
submission_id UUID REFERENCES content_submissions(id),
|
||||
is_current BOOLEAN DEFAULT true,
|
||||
|
||||
-- All park fields replicated (RELATIONAL, not JSONB!)
|
||||
name TEXT,
|
||||
slug TEXT,
|
||||
description TEXT,
|
||||
park_type TEXT,
|
||||
status TEXT,
|
||||
opening_date DATE,
|
||||
closing_date DATE,
|
||||
opening_date_precision TEXT,
|
||||
closing_date_precision TEXT,
|
||||
location_id UUID,
|
||||
operator_id UUID,
|
||||
property_owner_id UUID,
|
||||
website_url TEXT,
|
||||
phone TEXT,
|
||||
email TEXT,
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT,
|
||||
|
||||
UNIQUE(park_id, version_number)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_park_versions_current ON park_versions(park_id, is_current) WHERE is_current = true;
|
||||
CREATE INDEX idx_park_versions_created ON park_versions(created_at DESC);
|
||||
```
|
||||
|
||||
Similar tables exist for: `ride_versions`, `company_versions`, `ride_model_versions`.
|
||||
|
||||
---
|
||||
|
||||
## Row-Level Security Patterns
|
||||
|
||||
### Pattern 1: Public Read, Moderation Write
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Public read access" ON {table} FOR SELECT USING (true);
|
||||
CREATE POLICY "Deny direct inserts" ON {table} FOR INSERT WITH CHECK (false);
|
||||
CREATE POLICY "Deny direct updates" ON {table} FOR UPDATE USING (false);
|
||||
```
|
||||
|
||||
### Pattern 2: User-Scoped Data
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Users manage own" ON {table} FOR ALL
|
||||
USING (auth.uid() = user_id);
|
||||
```
|
||||
|
||||
### Pattern 3: Privacy-Filtered
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Privacy filtered" ON profiles FOR SELECT
|
||||
USING (get_filtered_profile(user_id, auth.uid()) IS NOT NULL);
|
||||
```
|
||||
|
||||
### Pattern 4: Moderator+ Access with MFA
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Moderators can manage" ON {table} FOR ALL
|
||||
USING (
|
||||
is_moderator(auth.uid()) AND
|
||||
(NOT has_mfa_enabled(auth.uid()) OR has_aal2())
|
||||
);
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Helper Functions
|
||||
|
||||
### is_moderator()
|
||||
|
||||
```sql
|
||||
CREATE FUNCTION is_moderator(user_id UUID) RETURNS BOOLEAN AS $$
|
||||
SELECT EXISTS (
|
||||
SELECT 1 FROM user_roles
|
||||
WHERE user_id = $1 AND role IN ('moderator', 'admin', 'superuser')
|
||||
);
|
||||
$$ LANGUAGE SQL STABLE SECURITY DEFINER;
|
||||
```
|
||||
|
||||
### get_filtered_profile()
|
||||
|
||||
Implements privacy filtering based on privacy_level.
|
||||
|
||||
```sql
|
||||
CREATE FUNCTION get_filtered_profile(
|
||||
profile_user_id UUID,
|
||||
requesting_user_id UUID
|
||||
) RETURNS profiles AS $$
|
||||
-- Complex logic to filter based on privacy settings
|
||||
$$ LANGUAGE SQL STABLE SECURITY DEFINER;
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Indexing Strategy
|
||||
|
||||
```sql
|
||||
-- Entity lookups
|
||||
CREATE INDEX idx_parks_slug ON parks(slug);
|
||||
CREATE INDEX idx_rides_park ON rides(park_id);
|
||||
CREATE INDEX idx_rides_status ON rides(status);
|
||||
|
||||
-- Moderation queue
|
||||
CREATE INDEX idx_submissions_status ON content_submissions(status) WHERE status IN ('pending', 'partially_approved');
|
||||
CREATE INDEX idx_submissions_assigned ON content_submissions(assigned_to, locked_until);
|
||||
|
||||
-- View tracking
|
||||
CREATE INDEX idx_page_views_entity ON entity_page_views(entity_type, entity_id, viewed_at DESC);
|
||||
|
||||
-- User credits
|
||||
CREATE INDEX idx_ride_credits_user ON user_ride_credits(user_id, sort_order);
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
**See Also:**
|
||||
- [FRONTEND_ARCHITECTURE.md](./FRONTEND_ARCHITECTURE.md) - How frontend interacts with database
|
||||
- [SUBMISSION_FLOW.md](./SUBMISSION_FLOW.md) - How submissions flow through moderation
|
||||
- [versioning/SCHEMA.md](./versioning/SCHEMA.md) - Detailed versioning system
|
||||
Reference in New Issue
Block a user