125 lines
5.4 KiB
SQL
125 lines
5.4 KiB
SQL
DROP DATABASE IF EXISTS locutus;
|
|
CREATE DATABASE locutus;
|
|
|
|
\c locutus
|
|
|
|
\set id_regex '''^[A-Za-z0-9_-]{43}$'''
|
|
|
|
CREATE TABLE domains
|
|
(
|
|
domain_id CHAR(43) NOT NULL,
|
|
domain_name VARCHAR(256) NOT NULL,
|
|
|
|
CONSTRAINT pk_domains PRIMARY KEY (domain_id),
|
|
CONSTRAINT sk_domains UNIQUE (domain_name),
|
|
CONSTRAINT domains_domain_name CHECK (domain_name ~ '^([a-z0-9_-]+\.)+[a-z]{2,}$'),
|
|
CONSTRAINT domains_domain_id CHECK (domain_id ~ :id_regex)
|
|
);
|
|
|
|
CREATE TABLE accounts
|
|
(
|
|
account_id CHAR(43) NOT NULL,
|
|
domain_id CHAR(43) NOT NULL,
|
|
account_name VARCHAR(256) NOT NULL,
|
|
|
|
CONSTRAINT pk_accounts PRIMARY KEY (account_id),
|
|
CONSTRAINT sk_accounts UNIQUE (domain_id, account_name),
|
|
CONSTRAINT fk_accounts_domains FOREIGN KEY (domain_id) REFERENCES domains (domain_id),
|
|
CONSTRAINT accounts_account_id CHECK (account_id ~ :id_regex)
|
|
);
|
|
|
|
CREATE TABLE rooms
|
|
(
|
|
room_id CHAR(43) NOT NULL,
|
|
room_name VARCHAR(256),
|
|
|
|
CONSTRAINT pk_rooms PRIMARY KEY (room_id),
|
|
CONSTRAINT rooms_room_id CHECK (room_id ~ :id_regex)
|
|
);
|
|
|
|
CREATE TABLE events
|
|
(
|
|
event_id CHAR(43) NOT NULL,
|
|
room_id CHAR(43) NOT NULL,
|
|
from_member_id CHAR(43) NOT NULL,
|
|
from_session_id CHAR(43) NOT NULL,
|
|
to_session_id CHAR(43) DEFAULT NULL,
|
|
|
|
client_ts TIMESTAMP WITHOUT TIME ZONE DEFAULT NULL,
|
|
client_tz INTEGER DEFAULT NULL,
|
|
server_ts TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT (now() at time zone 'utc'),
|
|
server_tz INTEGER DEFAULT NULL,
|
|
domain_ts TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT (now() at time zone 'utc'),
|
|
domain_tz INTEGER DEFAULT NULL,
|
|
|
|
data JSONB NOT NULL,
|
|
|
|
CONSTRAINT pk_events PRIMARY KEY (event_id),
|
|
CONSTRAINT sk_events UNIQUE (room_id, event_id),
|
|
CONSTRAINT fk_events_rooms FOREIGN KEY (room_id) REFERENCES rooms (room_id),
|
|
CONSTRAINT events_event_id CHECK (event_id ~ :id_regex),
|
|
CONSTRAINT events_from_member_id CHECK (from_member_id ~ :id_regex),
|
|
CONSTRAINT events_from_session_id CHECK (from_session_id ~ :id_regex),
|
|
CONSTRAINT events_to_session_id CHECK (to_session_id ~ :id_regex)
|
|
);
|
|
CREATE INDEX idx_events_client_ts ON events (client_ts);
|
|
CREATE INDEX idx_events_server_ts ON events (server_ts);
|
|
CREATE INDEX idx_events_domain_ts ON events (domain_ts);
|
|
|
|
CREATE TABLE members
|
|
(
|
|
member_id CHAR(43) NOT NULL,
|
|
domain_id CHAR(43) NOT NULL,
|
|
room_id CHAR(43) NOT NULL,
|
|
account_id CHAR(43),
|
|
last_event_domain CHAR(43),
|
|
last_event_session CHAR(43),
|
|
last_event_read CHAR(43),
|
|
|
|
CONSTRAINT pk_members PRIMARY KEY (member_id),
|
|
CONSTRAINT sk_members UNIQUE (member_id, room_id),
|
|
CONSTRAINT fk_members_domains FOREIGN KEY (domain_id) REFERENCES domains (domain_id),
|
|
CONSTRAINT fk_members_rooms FOREIGN KEY (room_id) REFERENCES rooms (room_id),
|
|
CONSTRAINT fk_members_accounts FOREIGN KEY (account_id) REFERENCES accounts (account_id),
|
|
CONSTRAINT fk_members_last_event_domain FOREIGN KEY (room_id, last_event_domain) REFERENCES events (room_id, event_id),
|
|
CONSTRAINT fk_members_last_event_session FOREIGN KEY (room_id, last_event_session) REFERENCES events (room_id, event_id),
|
|
CONSTRAINT fk_members_last_event_read FOREIGN KEY (room_id, last_event_read) REFERENCES events (room_id, event_id),
|
|
CONSTRAINT members_member_id CHECK (member_id ~ :id_regex)
|
|
);
|
|
|
|
CREATE TABLE sessions
|
|
(
|
|
account_id CHAR(43) NOT NULL,
|
|
session_nr INTEGER NOT NULL DEFAULT 1,
|
|
session_token VARCHAR(256) NOT NULL,
|
|
session_name VARCHAR(256) DEFAULT NULL,
|
|
active BOOLEAN NOT NULL DEFAULT TRUE,
|
|
|
|
first_used TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT (now() at time zone 'utc'),
|
|
first_used_tz INTEGER DEFAULT NULL,
|
|
last_used TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT (now() at time zone 'utc'),
|
|
last_used_tz INTEGER DEFAULT NULL,
|
|
|
|
CONSTRAINT pk_sessions PRIMARY KEY (account_id, session_nr),
|
|
CONSTRAINT sk_sessions UNIQUE (session_token),
|
|
CONSTRAINT fk_sessions_accounts FOREIGN KEY (account_id) REFERENCES accounts (account_id)
|
|
);
|
|
|
|
INSERT INTO domains (domain_id, domain_name)
|
|
VALUES ('wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA', 'necronda.net');
|
|
|
|
INSERT INTO accounts (account_id, domain_id, account_name)
|
|
VALUES ('g_Ip_bkfpfT73USemt16PCyGcLKBkPmclVjsrKv51Po', 'wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA', 'lorenz'),
|
|
('X1j7UKLCwMTB3DbTuZvJxOBGoVDnApCjI894yAE7RFc', 'wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA', 'tom');
|
|
|
|
INSERT INTO rooms (room_id, room_name)
|
|
VALUES ('60nc0XXDIYUh6QzX4p0rMpCdzDmxghZLZk8dLuQh628', NULL);
|
|
|
|
INSERT INTO members (member_id, domain_id, room_id, account_id)
|
|
VALUES ('AbyhKNXgv4FDsm5Iq2p0RSHZr0cJ1ueBDL0UDMnV__4', 'wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA',
|
|
'60nc0XXDIYUh6QzX4p0rMpCdzDmxghZLZk8dLuQh628', 'g_Ip_bkfpfT73USemt16PCyGcLKBkPmclVjsrKv51Po'),
|
|
('vs2C345OEZVqxxWxTAX5EfCjTxyM8cpp0993sP0vZ7M', 'wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA',
|
|
'60nc0XXDIYUh6QzX4p0rMpCdzDmxghZLZk8dLuQh628', 'X1j7UKLCwMTB3DbTuZvJxOBGoVDnApCjI894yAE7RFc');
|
|
|
|
|