71 lines
2.5 KiB
SQL
71 lines
2.5 KiB
SQL
-- PostgreSQL schema scaffold for dvv tunnel SaaS platform.
|
|
|
|
create extension if not exists pgcrypto;
|
|
|
|
create table if not exists users (
|
|
id uuid primary key default gen_random_uuid(),
|
|
email text unique not null,
|
|
password_hash text,
|
|
created_at timestamptz not null default now(),
|
|
updated_at timestamptz not null default now()
|
|
);
|
|
|
|
create table if not exists plans (
|
|
id text primary key,
|
|
name text not null,
|
|
max_tunnels integer not null,
|
|
custom_subdomain boolean not null default false,
|
|
idle_timeout_seconds integer,
|
|
bandwidth_cap_kbps integer,
|
|
priority_routing boolean not null default false,
|
|
created_at timestamptz not null default now()
|
|
);
|
|
|
|
create table if not exists subscriptions (
|
|
id uuid primary key default gen_random_uuid(),
|
|
user_id uuid not null references users(id) on delete cascade,
|
|
plan_id text not null references plans(id),
|
|
provider text not null default 'stripe',
|
|
provider_customer_id text,
|
|
provider_subscription_id text,
|
|
status text not null,
|
|
current_period_end timestamptz,
|
|
created_at timestamptz not null default now(),
|
|
updated_at timestamptz not null default now()
|
|
);
|
|
|
|
create index if not exists subscriptions_user_id_idx on subscriptions(user_id);
|
|
create unique index if not exists subscriptions_provider_subscription_id_uidx
|
|
on subscriptions(provider_subscription_id)
|
|
where provider_subscription_id is not null;
|
|
|
|
create table if not exists tunnels (
|
|
id uuid primary key default gen_random_uuid(),
|
|
user_id uuid not null references users(id) on delete cascade,
|
|
region text not null check (region in ('eu', 'us', 'asia')),
|
|
subdomain text not null,
|
|
custom_domain boolean not null default false,
|
|
active boolean not null default true,
|
|
created_at timestamptz not null default now(),
|
|
updated_at timestamptz not null default now(),
|
|
unique (region, subdomain)
|
|
);
|
|
|
|
create index if not exists tunnels_user_id_idx on tunnels(user_id);
|
|
|
|
create table if not exists usage_rollups_hourly (
|
|
user_id uuid not null references users(id) on delete cascade,
|
|
hour_bucket timestamptz not null,
|
|
bytes_in bigint not null default 0,
|
|
bytes_out bigint not null default 0,
|
|
player_connections integer not null default 0,
|
|
primary key (user_id, hour_bucket)
|
|
);
|
|
|
|
insert into plans (id, name, max_tunnels, custom_subdomain, idle_timeout_seconds, bandwidth_cap_kbps, priority_routing)
|
|
values
|
|
('free', 'Free', 1, false, 900, 512, false),
|
|
('pro', 'Pro', 5, true, null, 8192, true),
|
|
('team', 'Team', 25, true, null, null, true)
|
|
on conflict (id) do nothing;
|