db/do.sql
2025-08-06 13:44:21 +02:00

246 lines
7.1 KiB
PL/PgSQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- --------------------------------------------------------------
-- do.sql create tables for HeroLedger models (PostgreSQL)
-- --------------------------------------------------------------
BEGIN;
-- 1. DNSZONE
CREATE TABLE dnszone (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
domain TEXT, -- @[index]
administrators INTEGER[], -- array of user ids
status TEXT,
metadata JSONB,
soarecord JSONB, -- store array of SOARecord structs as JSONB
data JSONB NOT NULL
);
CREATE INDEX idx_dnszone_domain ON dnszone(domain);
-- 2. DNSRECORD
CREATE TABLE dnsrecord (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
subdomain TEXT,
record_type TEXT,
value TEXT,
priority INTEGER,
ttl INTEGER,
is_active BOOLEAN,
cat TEXT,
is_wildcard BOOLEAN,
data JSONB NOT NULL
);
-- No explicit index required rarely queried alone
-- 3. GROUP
CREATE TABLE "group" (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
name TEXT NOT NULL,
description TEXT,
dnsrecords INTEGER[], -- FK → dnsrecord.id (array)
administrators INTEGER[],
config JSONB, -- embedded GroupConfig struct
status TEXT,
visibility TEXT,
created_ts BIGINT,
updated_ts BIGINT,
data JSONB NOT NULL
);
CREATE UNIQUE INDEX idx_group_name ON "group"(name);
-- 4. USER_GROUP_MEMBERSHIP
CREATE TABLE user_group_membership (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
user_id INTEGER NOT NULL,
group_ids INTEGER[], -- array of group ids
data JSONB NOT NULL
);
CREATE INDEX idx_ugm_user_id ON user_group_membership(user_id);
CREATE INDEX idx_ugm_group_ids ON user_group_membership USING GIN (group_ids);
-- 5. MEMBER (circle/member.v)
CREATE TABLE member (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
user_id INTEGER NOT NULL,
role TEXT,
status TEXT,
joined_at BIGINT,
invited_by INTEGER,
permissions TEXT[],
data JSONB NOT NULL
);
CREATE INDEX idx_member_user_id ON member(user_id);
-- 6. ACCOUNT
CREATE TABLE account (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
owner_id INTEGER,
address TEXT NOT NULL,
balance DOUBLE PRECISION,
currency TEXT,
assetid INTEGER,
last_activity BIGINT,
administrators INTEGER[],
accountpolicy INTEGER,
data JSONB NOT NULL
);
CREATE UNIQUE INDEX idx_account_address ON account(address);
CREATE INDEX idx_account_assetid ON account(assetid);
-- 7. ASSET
CREATE TABLE asset (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
address TEXT NOT NULL,
assetid INTEGER NOT NULL,
asset_type TEXT,
issuer INTEGER,
supply DOUBLE PRECISION,
decimals SMALLINT,
is_frozen BOOLEAN,
metadata JSONB,
administrators INTEGER[],
min_signatures INTEGER,
data JSONB NOT NULL
);
CREATE UNIQUE INDEX idx_asset_address ON asset(address);
CREATE UNIQUE INDEX idx_asset_assetid ON asset(assetid);
CREATE INDEX idx_asset_issuer ON asset(issuer);
-- 8. ACCOUNT_POLICY (holds three AccountPolicyItem JSONB blobs)
CREATE TABLE account_policy (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
transferpolicy JSONB,
adminpolicy JSONB,
clawbackpolicy JSONB,
freezepolicy JSONB,
data JSONB NOT NULL
);
-- 9. ACCOUNT_POLICY_ITEM (standalone if you ever need a table)
-- (optional we store it as JSONB inside account_policy, so not created)
-- 10. TRANSACTION
CREATE TABLE transaction (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
txid INTEGER NOT NULL,
source INTEGER,
destination INTEGER,
assetid INTEGER,
amount DOUBLE PRECISION,
timestamp BIGINT,
status TEXT,
memo TEXT,
tx_type TEXT,
signatures JSONB, -- array of Signature JSON objects
data JSONB NOT NULL
);
CREATE UNIQUE INDEX idx_transaction_txid ON transaction(txid);
CREATE INDEX idx_transaction_source ON transaction(source);
CREATE INDEX idx_transaction_destination ON transaction(destination);
CREATE INDEX idx_transaction_assetid ON transaction(assetid);
-- 11. SIGNATURE
CREATE TABLE signature (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
signature_id INTEGER NOT NULL,
user_id INTEGER NOT NULL,
value TEXT,
objectid INTEGER,
objecttype TEXT,
status TEXT,
timestamp BIGINT,
data JSONB NOT NULL
);
CREATE INDEX idx_signature_signature_id ON signature(signature_id);
CREATE INDEX idx_signature_user_id ON signature(user_id);
CREATE INDEX idx_signature_objectid ON signature(objectid);
-- 12. USER_KVS
CREATE TABLE user_kvs (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
userid INTEGER NOT NULL,
name TEXT,
data JSONB NOT NULL
);
CREATE INDEX idx_userkvs_userid ON user_kvs(userid);
-- 13. USER_KVS_ITEM
CREATE TABLE user_kvs_item (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
userkvs_id INTEGER NOT NULL,
key TEXT NOT NULL,
value TEXT,
secretbox JSONB,
timestamp BIGINT,
data JSONB NOT NULL
);
CREATE INDEX idx_userkvs_item_userkvs_id ON user_kvs_item(userkvs_id);
CREATE INDEX idx_userkvs_item_key ON user_kvs_item(key);
-- 14. USER
CREATE TABLE "user" (
id SERIAL PRIMARY KEY,
created BIGINT,
updated BIGINT,
deleted BOOLEAN,
version INTEGER,
username TEXT NOT NULL,
pubkey TEXT NOT NULL,
email TEXT[] NOT NULL,
status TEXT,
userprofile JSONB,
kyc JSONB,
data JSONB NOT NULL
);
CREATE UNIQUE INDEX idx_user_username ON "user"(username);
CREATE UNIQUE INDEX idx_user_pubkey ON "user"(pubkey);
-- Email array index use GIN for fast containment queries
CREATE INDEX idx_user_email ON "user" USING GIN (email);
COMMIT;