init
This commit is contained in:
commit
d69342b2e9
160 changed files with 28681 additions and 0 deletions
185
internal/db/migrations/001_initial.sql
Normal file
185
internal/db/migrations/001_initial.sql
Normal file
|
|
@ -0,0 +1,185 @@
|
|||
-- Users (provider-agnostic)
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
email VARCHAR(255) UNIQUE NOT NULL,
|
||||
name VARCHAR(255),
|
||||
avatar_url TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- OAuth identities
|
||||
CREATE TABLE IF NOT EXISTS user_identities (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
provider VARCHAR(50) NOT NULL,
|
||||
provider_id VARCHAR(255) NOT NULL,
|
||||
provider_email VARCHAR(255),
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
UNIQUE(provider, provider_id)
|
||||
);
|
||||
|
||||
-- Sessions
|
||||
CREATE TABLE IF NOT EXISTS sessions (
|
||||
token VARCHAR(64) PRIMARY KEY,
|
||||
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
expires_at TIMESTAMP WITH TIME ZONE NOT NULL
|
||||
);
|
||||
|
||||
-- Tenants (blog instances)
|
||||
CREATE TABLE IF NOT EXISTS tenants (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
owner_id UUID REFERENCES users(id) ON DELETE SET NULL,
|
||||
subdomain VARCHAR(63) UNIQUE NOT NULL,
|
||||
custom_domain VARCHAR(255),
|
||||
premium BOOLEAN DEFAULT FALSE,
|
||||
members_enabled BOOLEAN DEFAULT FALSE,
|
||||
donations_enabled BOOLEAN DEFAULT FALSE,
|
||||
auth_google_enabled BOOLEAN DEFAULT TRUE,
|
||||
auth_github_enabled BOOLEAN DEFAULT TRUE,
|
||||
auth_discord_enabled BOOLEAN DEFAULT TRUE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Demos (temporary blogs)
|
||||
CREATE TABLE IF NOT EXISTS demos (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
subdomain VARCHAR(63) UNIQUE NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
expires_at TIMESTAMP WITH TIME ZONE NOT NULL
|
||||
);
|
||||
|
||||
-- Reserved subdomains
|
||||
CREATE TABLE IF NOT EXISTS reserved_subdomains (
|
||||
subdomain VARCHAR(63) PRIMARY KEY,
|
||||
reason VARCHAR(255)
|
||||
);
|
||||
|
||||
-- Membership tiers
|
||||
CREATE TABLE IF NOT EXISTS membership_tiers (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
name VARCHAR(100) NOT NULL,
|
||||
price_cents INTEGER NOT NULL,
|
||||
description TEXT,
|
||||
benefits TEXT[],
|
||||
lemon_variant_id VARCHAR(64),
|
||||
active BOOLEAN DEFAULT TRUE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Subscriptions
|
||||
CREATE TABLE IF NOT EXISTS subscriptions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
|
||||
tier_id UUID REFERENCES membership_tiers(id) ON DELETE SET NULL,
|
||||
tier_name VARCHAR(100) NOT NULL,
|
||||
status VARCHAR(20) NOT NULL,
|
||||
lemon_subscription_id VARCHAR(64) UNIQUE,
|
||||
lemon_customer_id VARCHAR(64),
|
||||
amount_cents INTEGER NOT NULL,
|
||||
current_period_start TIMESTAMP WITH TIME ZONE,
|
||||
current_period_end TIMESTAMP WITH TIME ZONE,
|
||||
cancelled_at TIMESTAMP WITH TIME ZONE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Donations
|
||||
CREATE TABLE IF NOT EXISTS donations (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
|
||||
donor_email VARCHAR(255),
|
||||
donor_name VARCHAR(255),
|
||||
amount_cents INTEGER NOT NULL,
|
||||
lemon_order_id VARCHAR(64) UNIQUE,
|
||||
message TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Earnings ledger
|
||||
CREATE TABLE IF NOT EXISTS earnings (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
source_type VARCHAR(20) NOT NULL,
|
||||
source_id UUID NOT NULL,
|
||||
description TEXT,
|
||||
gross_cents INTEGER NOT NULL,
|
||||
platform_fee_cents INTEGER NOT NULL,
|
||||
processor_fee_cents INTEGER NOT NULL,
|
||||
net_cents INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Balances
|
||||
CREATE TABLE IF NOT EXISTS balances (
|
||||
tenant_id UUID PRIMARY KEY REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
available_cents INTEGER DEFAULT 0,
|
||||
lifetime_earnings_cents INTEGER DEFAULT 0,
|
||||
lifetime_paid_cents INTEGER DEFAULT 0,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Payouts
|
||||
CREATE TABLE IF NOT EXISTS payouts (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
amount_cents INTEGER NOT NULL,
|
||||
currency VARCHAR(3) DEFAULT 'USD',
|
||||
wise_transfer_id VARCHAR(64),
|
||||
wise_quote_id VARCHAR(64),
|
||||
status VARCHAR(20) NOT NULL,
|
||||
failure_reason TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
completed_at TIMESTAMP WITH TIME ZONE
|
||||
);
|
||||
|
||||
-- Payout settings
|
||||
CREATE TABLE IF NOT EXISTS payout_settings (
|
||||
tenant_id UUID PRIMARY KEY REFERENCES tenants(id) ON DELETE CASCADE,
|
||||
wise_recipient_id VARCHAR(64),
|
||||
account_holder_name VARCHAR(255),
|
||||
currency VARCHAR(3) DEFAULT 'USD',
|
||||
payout_email VARCHAR(255),
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_identities_lookup ON user_identities(provider, provider_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_identities_user ON user_identities(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_expires ON sessions(expires_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_user ON sessions(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_tenants_owner ON tenants(owner_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_tenants_subdomain ON tenants(subdomain);
|
||||
CREATE INDEX IF NOT EXISTS idx_demos_expires ON demos(expires_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_demos_subdomain ON demos(subdomain);
|
||||
CREATE INDEX IF NOT EXISTS idx_tiers_tenant ON membership_tiers(tenant_id) WHERE active = TRUE;
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_tenant ON subscriptions(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_user ON subscriptions(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_lemon ON subscriptions(lemon_subscription_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_donations_tenant ON donations(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_earnings_tenant ON earnings(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_payouts_tenant ON payouts(tenant_id);
|
||||
|
||||
-- Reserved subdomains
|
||||
INSERT INTO reserved_subdomains (subdomain, reason) VALUES
|
||||
('www', 'system'),
|
||||
('api', 'system'),
|
||||
('app', 'system'),
|
||||
('admin', 'system'),
|
||||
('staging', 'system'),
|
||||
('demo', 'system'),
|
||||
('test', 'system'),
|
||||
('mail', 'system'),
|
||||
('smtp', 'system'),
|
||||
('ftp', 'system'),
|
||||
('ssh', 'system'),
|
||||
('traefik', 'system'),
|
||||
('ops', 'system'),
|
||||
('source', 'system'),
|
||||
('ci', 'system')
|
||||
ON CONFLICT (subdomain) DO NOTHING;
|
||||
Loading…
Add table
Add a link
Reference in a new issue