forked from blasthavers/blastmud
107 lines
3.9 KiB
SQL
107 lines
3.9 KiB
SQL
-- Note database created is ephemeral and use for migra to diff only.
|
|
-- Never put data in it, or it will be lost.
|
|
DROP DATABASE IF EXISTS blast_schemaonly;
|
|
CREATE DATABASE blast_schemaonly;
|
|
|
|
\c blast_schemaonly
|
|
|
|
CREATE TABLE listeners (
|
|
listener UUID NOT NULL PRIMARY KEY,
|
|
last_seen TIMESTAMPTZ
|
|
);
|
|
|
|
CREATE TABLE sessions (
|
|
session UUID NOT NULL PRIMARY KEY,
|
|
listener UUID NOT NULL,
|
|
details JSONB NOT NULL
|
|
);
|
|
CREATE INDEX session_by_listener ON sessions(listener);
|
|
|
|
CREATE SEQUENCE item_seq;
|
|
|
|
CREATE TABLE items (
|
|
item_id BIGSERIAL NOT NULL PRIMARY KEY,
|
|
details JSONB NOT NULL
|
|
);
|
|
CREATE UNIQUE INDEX item_index ON items ((details->>'item_type'), (details->>'item_code'));
|
|
CREATE INDEX item_by_loc ON items ((details->>'location'));
|
|
CREATE INDEX item_by_static ON items ((cast(details->>'is_static' as boolean)));
|
|
CREATE INDEX item_by_display ON items (lower(details->>'display'));
|
|
CREATE INDEX item_by_owner ON items (lower(details->>'owner'));
|
|
CREATE INDEX item_by_following ON items ((details->'following'->>'follow_whom'));
|
|
CREATE UNIQUE INDEX item_dynamic_entrance ON items (
|
|
(details->'dynamic_entrance'->>'source_item'),
|
|
(LOWER(details->'dynamic_entrance'->>'direction')));
|
|
CREATE INDEX item_id_with_urges ON items (item_id) WHERE details->'flags' @> '"HasUrges"';
|
|
|
|
CREATE TABLE users (
|
|
-- Username here is all lower case, but details has correct case version.
|
|
username TEXT NOT NULL PRIMARY KEY,
|
|
current_session UUID REFERENCES sessions(session),
|
|
current_listener UUID REFERENCES listeners(listener),
|
|
details JSONB NOT NULL
|
|
);
|
|
CREATE INDEX user_by_listener ON users(current_listener);
|
|
CREATE INDEX user_by_session ON users(current_session);
|
|
|
|
CREATE UNLOGGED TABLE sendqueue (
|
|
item BIGSERIAL NOT NULL PRIMARY KEY,
|
|
session UUID NOT NULL REFERENCES sessions(session),
|
|
listener UUID REFERENCES listeners(listener),
|
|
message TEXT, /* Nullable, null means disconnect */
|
|
sent_at TIMESTAMPTZ
|
|
);
|
|
|
|
CREATE TABLE abuselog (
|
|
id UUID NOT NULL PRIMARY KEY,
|
|
triggered_by TEXT NOT NULL,
|
|
logdata JSONB NOT NULL,
|
|
expires TIMESTAMPTZ NOT NULL
|
|
);
|
|
CREATE INDEX abuselog_by_triggerer ON abuselog(triggered_by);
|
|
CREATE INDEX abuselog_by_expires ON abuselog(expires);
|
|
|
|
CREATE TABLE tasks (
|
|
task_id BIGSERIAL NOT NULL PRIMARY KEY,
|
|
details JSONB NOT NULL
|
|
);
|
|
CREATE UNIQUE INDEX tasks_by_code_type ON tasks((details->>'task_code'), (details->>'task_type'));
|
|
CREATE INDEX tasks_by_static ON tasks((cast(details->>'is_static' as boolean)));
|
|
CREATE INDEX tasks_by_scheduled ON tasks((details->>'next_scheduled'));
|
|
|
|
CREATE SEQUENCE task_seq;
|
|
|
|
CREATE TABLE corps (
|
|
corp_id BIGSERIAL NOT NULL PRIMARY KEY,
|
|
details JSONB NOT NULL
|
|
);
|
|
CREATE INDEX corp_by_name ON corps((LOWER(details->>'name')));
|
|
CREATE TABLE corp_membership (
|
|
corp_id BIGSERIAL NOT NULL REFERENCES corps(corp_id),
|
|
member_username TEXT NOT NULL REFERENCES users(username),
|
|
details JSONB NOT NULL,
|
|
PRIMARY KEY (corp_id, member_username)
|
|
);
|
|
CREATE INDEX corp_membership_by_username ON corp_membership(member_username);
|
|
CREATE INDEX corp_membership_by_invited ON corp_membership((details->>'invited_at'));
|
|
|
|
CREATE TABLE user_consent (
|
|
consenting_user TEXT NOT NULL REFERENCES users(username),
|
|
consented_user TEXT NOT NULL REFERENCES users(username),
|
|
consent_type TEXT NOT NULL,
|
|
details JSONB NOT NULL,
|
|
PRIMARY KEY (consenting_user, consented_user, consent_type)
|
|
);
|
|
CREATE INDEX user_consent_by_consented ON user_consent (consented_user);
|
|
CREATE INDEX user_consent_by_expires ON user_consent ((details->>'expires'));
|
|
|
|
CREATE TABLE corp_consent (
|
|
consenting_corp BIGINT NOT NULL REFERENCES corps(corp_id),
|
|
consented_corp BIGINT NOT NULL REFERENCES corps(corp_id),
|
|
consent_type TEXT NOT NULL,
|
|
details JSONB NOT NULL,
|
|
PRIMARY KEY (consenting_corp, consented_corp, consent_type)
|
|
);
|
|
CREATE INDEX corp_consent_by_consented ON corp_consent (consented_corp);
|
|
CREATE INDEX corp_consent_by_expires ON corp_consent ((details->>'expires'));
|