delphi.market/db/schema.sql

81 lines
2.5 KiB
PL/PgSQL

CREATE TABLE users(
id SERIAL PRIMARY KEY,
name TEXT UNIQUE NOT NULL DEFAULT LEFT(md5(random()::text), 8),
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
ln_pubkey TEXT UNIQUE,
nostr_pubkey TEXT UNIQUE,
msats BIGINT NOT NULL DEFAULT 0
);
CREATE TABLE sessions(
id VARCHAR(48) PRIMARY KEY,
user_id INTEGER NOT NULL REFERENCES users(id),
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE lnauth(
k1 VARCHAR(64) PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
lnurl TEXT NOT NULL,
session_id VARCHAR(48) NOT NULL DEFAULT encode(gen_random_uuid()::text::bytea, 'base64')
);
CREATE TABLE invoices(
id SERIAL PRIMARY KEY,
user_id INTEGER NOT NULL REFERENCES users(id),
msats BIGINT NOT NULL,
msats_received BIGINT,
hash TEXT NOT NULL UNIQUE,
bolt11 TEXT NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
confirmed_at TIMESTAMP WITH TIME ZONE,
held_since TIMESTAMP WITH TIME ZONE,
description TEXT
);
CREATE TABLE markets(
id SERIAL PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
question TEXT NOT NULL,
description TEXT,
end_date TIMESTAMP WITH TIME ZONE NOT NULL,
settled_at TIMESTAMP WITH TIME ZONE,
user_id INTEGER NOT NULL REFERENCES users(id),
invoice_id INTEGER NOT NULL UNIQUE REFERENCES invoices(id),
lmsr_b FLOAT NOT NULL
);
CREATE TABLE orders(
id SERIAL PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
market_id INTEGER NOT NULL REFERENCES markets(id),
user_id INTEGER NOT NULL REFERENCES users(id),
quantity BIGINT NOT NULL,
outcome INTEGER NOT NULL,
invoice_id INTEGER REFERENCES invoices(id)
);
CREATE TABLE withdrawals(
id SERIAL PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
canceled_at TIMESTAMP WITH TIME ZONE,
user_id INTEGER NOT NULL REFERENCES users(id),
bolt11 TEXT NOT NULL UNIQUE,
paid_at TIMESTAMP WITH TIME ZONE
);
CREATE FUNCTION lmsr(b FLOAT, q1 FLOAT, q2 FLOAT)
RETURNS FLOAT AS $$
BEGIN
RETURN b * LN(EXP(q1 / b) + EXP(q2 / b));
END;
$$ LANGUAGE plpgsql;
CREATE FUNCTION quote(b FLOAT, q1 FLOAT, q2 FLOAT, dq1 FLOAT)
RETURNS FLOAT AS $$
BEGIN
RETURN lmsr(b, q1+dq1, q2) - lmsr(b, q1, q2);
END;
$$ LANGUAGE plpgsql;