-- Enable useful extensions (optional) CREATE EXTENSION IF NOT EXISTS pgcrypto; -- for digests/hashes if you want CREATE EXTENSION IF NOT EXISTS btree_gist; -- for exclusion/partial indexes -- ========================= -- Core: Accounts & Currency -- ========================= CREATE TABLE accounts ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pubkey BYTEA NOT NULL UNIQUE, display_name TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT now(), CHECK (id >= 0) ); CREATE TABLE currencies ( asset_code TEXT PRIMARY KEY, -- e.g. "USDC-ETH", "EUR", "LND" name TEXT NOT NULL, symbol TEXT, -- e.g. "$", "€" decimals INT NOT NULL DEFAULT 2, -- how many decimal places UNIQUE (name) ); -- ========================= -- Services & Groups -- ========================= CREATE TYPE billing_mode AS ENUM ('per_second', 'per_request'); CREATE TABLE services ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, description TEXT, default_billing_mode billing_mode NOT NULL, default_price NUMERIC(38, 18) NOT NULL, -- default price in "unit currency" (see accepted currencies) default_currency TEXT NOT NULL REFERENCES currencies(asset_code) ON UPDATE CASCADE, max_request_seconds INTEGER, -- nullable means no cap schema_heroscript TEXT, schema_json JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT now(), CHECK (id >= 0), CHECK (default_price >= 0), CHECK (max_request_seconds IS NULL OR max_request_seconds > 0) ); -- Accepted currencies for a service (subset + optional specific price per currency) CREATE TABLE service_accepted_currencies ( service_id BIGINT NOT NULL REFERENCES services(id) ON DELETE CASCADE, asset_code TEXT NOT NULL REFERENCES currencies(asset_code) ON UPDATE CASCADE, price_override NUMERIC(38, 18), -- if set, overrides default_price for this currency billing_mode_override billing_mode, -- if set, overrides default_billing_mode PRIMARY KEY (service_id, asset_code), CHECK (price_override IS NULL OR price_override >= 0) ); CREATE TABLE service_groups ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, description TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT now(), CHECK (id >= 0) ); CREATE TABLE service_group_members ( group_id BIGINT NOT NULL REFERENCES service_groups(id) ON DELETE CASCADE, service_id BIGINT NOT NULL REFERENCES services(id) ON DELETE RESTRICT, PRIMARY KEY (group_id, service_id) ); -- ========================= -- Providers, Runners, Routing -- ========================= CREATE TABLE service_providers ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, account_id BIGINT NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, -- provider is an account name TEXT NOT NULL, description TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT now(), UNIQUE (name), CHECK (id >= 0) ); -- Providers can offer groups (which imply their services) CREATE TABLE provider_service_groups ( provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE CASCADE, group_id BIGINT NOT NULL REFERENCES service_groups(id) ON DELETE CASCADE, PRIMARY KEY (provider_id, group_id) ); -- Providers may set per-service overrides (price/mode/max seconds) (optionally per currency) CREATE TABLE provider_service_overrides ( provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE CASCADE, service_id BIGINT NOT NULL REFERENCES services(id) ON DELETE CASCADE, asset_code TEXT REFERENCES currencies(asset_code) ON UPDATE CASCADE, price_override NUMERIC(38, 18), billing_mode_override billing_mode, max_request_seconds_override INTEGER, PRIMARY KEY (provider_id, service_id, asset_code), CHECK (price_override IS NULL OR price_override >= 0), CHECK (max_request_seconds_override IS NULL OR max_request_seconds_override > 0) ); -- Runners CREATE TABLE runners ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, address INET NOT NULL, -- IPv6 (INET supports both IPv4/IPv6; require v6 via CHECK below if you like) name TEXT NOT NULL, description TEXT, pubkey BYTEA, -- optional created_at TIMESTAMPTZ NOT NULL DEFAULT now(), UNIQUE (address), CHECK (id >= 0), CHECK (family(address) = 6) -- ensure IPv6 ); -- Runner ownership: a runner can be owned by multiple providers CREATE TABLE runner_owners ( runner_id BIGINT NOT NULL REFERENCES runners(id) ON DELETE CASCADE, provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE CASCADE, PRIMARY KEY (runner_id, provider_id) ); -- Routing: link providers' services to specific runners CREATE TABLE provider_service_runners ( provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE CASCADE, service_id BIGINT NOT NULL REFERENCES services(id) ON DELETE CASCADE, runner_id BIGINT NOT NULL REFERENCES runners(id) ON DELETE CASCADE, PRIMARY KEY (provider_id, service_id, runner_id) ); -- Routing: link providers' service groups to runners CREATE TABLE provider_service_group_runners ( provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE CASCADE, group_id BIGINT NOT NULL REFERENCES service_groups(id) ON DELETE CASCADE, runner_id BIGINT NOT NULL REFERENCES runners(id) ON DELETE CASCADE, PRIMARY KEY (provider_id, group_id, runner_id) ); -- ========================= -- Subscriptions & Spend Control -- ========================= CREATE TYPE spend_period AS ENUM ('hour', 'day', 'month'); -- A subscription ties an account to a specific service OR a service group, with spend limits and allowed providers CREATE TABLE subscriptions ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, account_id BIGINT NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, service_id BIGINT REFERENCES services(id) ON DELETE CASCADE, group_id BIGINT REFERENCES service_groups(id) ON DELETE CASCADE, secret BYTEA NOT NULL, -- caller-chosen secret (consider storing a hash instead) subscription_data JSONB, -- arbitrary client-supplied info limit_amount NUMERIC(38, 18), -- allowed spend in the selected currency per period limit_currency TEXT REFERENCES currencies(asset_code) ON UPDATE CASCADE, limit_period spend_period, -- period for the limit active BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ NOT NULL DEFAULT now(), -- Ensure exactly one of service_id or group_id CHECK ( (service_id IS NOT NULL) <> (group_id IS NOT NULL) ), CHECK (limit_amount IS NULL OR limit_amount >= 0), CHECK (id >= 0) ); -- Providers that are allowed to serve under a subscription CREATE TABLE subscription_providers ( subscription_id BIGINT NOT NULL REFERENCES subscriptions(id) ON DELETE CASCADE, provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE CASCADE, PRIMARY KEY (subscription_id, provider_id) ); -- ========================= -- Usage, Requests & Billing -- ========================= -- A request lifecycle record (optional but useful for auditing and max duration enforcement) CREATE TYPE request_status AS ENUM ('pending', 'running', 'succeeded', 'failed', 'canceled'); CREATE TABLE requests ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, account_id BIGINT NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, subscription_id BIGINT NOT NULL REFERENCES subscriptions(id) ON DELETE RESTRICT, provider_id BIGINT NOT NULL REFERENCES service_providers(id) ON DELETE RESTRICT, service_id BIGINT NOT NULL REFERENCES services(id) ON DELETE RESTRICT, runner_id BIGINT REFERENCES runners(id) ON DELETE SET NULL, request_schema JSONB, -- concrete task payload (conforms to schema_json/heroscript) started_at TIMESTAMPTZ, ended_at TIMESTAMPTZ, status request_status NOT NULL DEFAULT 'pending', created_at TIMESTAMPTZ NOT NULL DEFAULT now(), CHECK (id >= 0), CHECK (ended_at IS NULL OR started_at IS NULL OR ended_at >= started_at) ); -- Billing ledger (debits/credits). Positive amount = debit to account (charge). Negative = credit/refund. CREATE TYPE ledger_entry_type AS ENUM ('debit', 'credit', 'adjustment'); CREATE TABLE billing_ledger ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, account_id BIGINT NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, provider_id BIGINT REFERENCES service_providers(id) ON DELETE SET NULL, service_id BIGINT REFERENCES services(id) ON DELETE SET NULL, request_id BIGINT REFERENCES requests(id) ON DELETE SET NULL, amount NUMERIC(38, 18) NOT NULL, -- positive for debit, negative for credit asset_code TEXT NOT NULL REFERENCES currencies(asset_code) ON UPDATE CASCADE, entry_type ledger_entry_type NOT NULL, description TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT now(), CHECK (id >= 0) ); -- Optional: running balances per account/currency (materialized view or real-time view) -- This is a plain view; for performance, you might maintain a cached table. CREATE VIEW account_balances AS SELECT account_id, asset_code, SUM(amount) AS balance FROM billing_ledger GROUP BY account_id, asset_code; -- ========================= -- Helpful Indexes -- ========================= CREATE INDEX idx_services_default_currency ON services(default_currency); CREATE INDEX idx_service_accepted_currencies_service ON service_accepted_currencies(service_id); CREATE INDEX idx_provider_overrides_service ON provider_service_overrides(service_id); CREATE INDEX idx_requests_account ON requests(account_id); CREATE INDEX idx_requests_provider ON requests(provider_id); CREATE INDEX idx_requests_service ON requests(service_id); CREATE INDEX idx_billing_account_currency ON billing_ledger(account_id, asset_code); CREATE INDEX idx_subscriptions_account_active ON subscriptions(account_id) WHERE active;