Update crates and change to UUID
This commit is contained in:
142
db/00.create.sql
142
db/00.create.sql
@ -3,47 +3,42 @@ CREATE DATABASE locutus;
|
||||
|
||||
\c locutus
|
||||
|
||||
\set id_regex '''^[A-Za-z0-9_-]{43}$'''
|
||||
|
||||
CREATE TABLE domains
|
||||
CREATE TABLE domain
|
||||
(
|
||||
domain_id CHAR(43) NOT NULL,
|
||||
domain_name VARCHAR(256) NOT NULL,
|
||||
domain_id UUID NOT NULL,
|
||||
domain_name TEXT 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)
|
||||
CONSTRAINT pk_domain PRIMARY KEY (domain_id),
|
||||
CONSTRAINT sk_domain UNIQUE (domain_name),
|
||||
CONSTRAINT domain_domain_name CHECK (domain_name ~ '^([a-z0-9_-]+\.)+[a-z]{2,}$')
|
||||
);
|
||||
|
||||
CREATE TABLE accounts
|
||||
CREATE TABLE account
|
||||
(
|
||||
account_id CHAR(43) NOT NULL,
|
||||
domain_id CHAR(43) NOT NULL,
|
||||
account_name VARCHAR(256) NOT NULL,
|
||||
account_id UUID NOT NULL,
|
||||
domain_id UUID NOT NULL,
|
||||
account_name TEXT 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)
|
||||
CONSTRAINT pk_account PRIMARY KEY (account_id),
|
||||
CONSTRAINT sk_account UNIQUE (domain_id, account_name),
|
||||
CONSTRAINT fk_account_domains FOREIGN KEY (domain_id) REFERENCES domain (domain_id)
|
||||
);
|
||||
|
||||
CREATE TABLE rooms
|
||||
CREATE TABLE room
|
||||
(
|
||||
room_id CHAR(43) NOT NULL,
|
||||
room_name VARCHAR(256),
|
||||
room_id UUID NOT NULL,
|
||||
room_name TEXT,
|
||||
|
||||
CONSTRAINT pk_rooms PRIMARY KEY (room_id),
|
||||
CONSTRAINT rooms_room_id CHECK (room_id ~ :id_regex)
|
||||
CONSTRAINT pk_room PRIMARY KEY (room_id)
|
||||
);
|
||||
|
||||
CREATE TABLE events
|
||||
CREATE TABLE event
|
||||
(
|
||||
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,
|
||||
event_id UUID NOT NULL,
|
||||
room_id UUID NOT NULL,
|
||||
from_member_id UUID NOT NULL,
|
||||
from_session_id UUID NOT NULL,
|
||||
to_session_id UUID DEFAULT NULL,
|
||||
|
||||
client_ts TIMESTAMP WITHOUT TIME ZONE DEFAULT NULL,
|
||||
client_tz INTEGER DEFAULT NULL,
|
||||
@ -54,46 +49,41 @@ CREATE TABLE events
|
||||
|
||||
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)
|
||||
CONSTRAINT pk_event PRIMARY KEY (event_id),
|
||||
CONSTRAINT sk_event UNIQUE (room_id, event_id),
|
||||
CONSTRAINT fk_event_rooms FOREIGN KEY (room_id) REFERENCES room (room_id)
|
||||
);
|
||||
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 INDEX idx_event_client_ts ON event (client_ts);
|
||||
CREATE INDEX idx_event_server_ts ON event (server_ts);
|
||||
CREATE INDEX idx_event_domain_ts ON event (domain_ts);
|
||||
|
||||
CREATE TABLE members
|
||||
CREATE TABLE member
|
||||
(
|
||||
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),
|
||||
member_id UUID NOT NULL,
|
||||
domain_id UUID NOT NULL,
|
||||
room_id UUID NOT NULL,
|
||||
account_id UUID,
|
||||
last_event_domain UUID,
|
||||
last_event_session UUID,
|
||||
last_event_read UUID,
|
||||
|
||||
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)
|
||||
CONSTRAINT pk_member PRIMARY KEY (member_id),
|
||||
CONSTRAINT sk_member UNIQUE (member_id, room_id),
|
||||
CONSTRAINT fk_member_domain FOREIGN KEY (domain_id) REFERENCES domain (domain_id),
|
||||
CONSTRAINT fk_member_room FOREIGN KEY (room_id) REFERENCES room (room_id),
|
||||
CONSTRAINT fk_member_account FOREIGN KEY (account_id) REFERENCES account (account_id),
|
||||
CONSTRAINT fk_member_last_event_domain FOREIGN KEY (room_id, last_event_domain) REFERENCES event (room_id, event_id),
|
||||
CONSTRAINT fk_member_last_event_session FOREIGN KEY (room_id, last_event_session) REFERENCES event (room_id, event_id),
|
||||
CONSTRAINT fk_member_last_event_read FOREIGN KEY (room_id, last_event_read) REFERENCES event (room_id, event_id)
|
||||
);
|
||||
|
||||
CREATE TABLE sessions
|
||||
CREATE TABLE session
|
||||
(
|
||||
session_id CHAR(43) NOT NULL,
|
||||
account_id CHAR(43) NOT NULL,
|
||||
session_id UUID NOT NULL,
|
||||
account_id UUID NOT NULL,
|
||||
session_nr INTEGER NOT NULL DEFAULT 1,
|
||||
session_token VARCHAR(256) NOT NULL,
|
||||
session_name VARCHAR(256) DEFAULT NULL,
|
||||
session_token TEXT NOT NULL,
|
||||
session_name TEXT DEFAULT NULL,
|
||||
active BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
|
||||
first_used TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT (now() at time zone 'utc'),
|
||||
@ -101,26 +91,26 @@ CREATE TABLE sessions
|
||||
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 (session_id),
|
||||
CONSTRAINT sk_sessions_1 UNIQUE (account_id, session_nr),
|
||||
CONSTRAINT sk_sessions_2 UNIQUE (session_token),
|
||||
CONSTRAINT fk_sessions_accounts FOREIGN KEY (account_id) REFERENCES accounts (account_id)
|
||||
CONSTRAINT pk_session PRIMARY KEY (session_id),
|
||||
CONSTRAINT sk_session_1 UNIQUE (account_id, session_nr),
|
||||
CONSTRAINT sk_session_2 UNIQUE (session_token),
|
||||
CONSTRAINT fk_session_account FOREIGN KEY (account_id) REFERENCES account (account_id)
|
||||
);
|
||||
|
||||
INSERT INTO domains (domain_id, domain_name)
|
||||
VALUES ('wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA', 'necronda.net');
|
||||
INSERT INTO domain (domain_id, domain_name)
|
||||
VALUES ('fe1b106c-18bc-4f85-943e-4950e0f3eb4f', 'necronda.net');
|
||||
|
||||
INSERT INTO accounts (account_id, domain_id, account_name)
|
||||
VALUES ('g_Ip_bkfpfT73USemt16PCyGcLKBkPmclVjsrKv51Po', 'wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA', 'lorenz'),
|
||||
('X1j7UKLCwMTB3DbTuZvJxOBGoVDnApCjI894yAE7RFc', 'wk2jFJku_7VvpM2hFIz2XBO0Yka9tLHwc6V0Yk8oYLA', 'tom');
|
||||
INSERT INTO account (account_id, domain_id, account_name)
|
||||
VALUES ('5c5dfc88-83f1-4933-b5cc-4a48eb735bfd', 'fe1b106c-18bc-4f85-943e-4950e0f3eb4f', 'lorenz'),
|
||||
('87fdbcb7-1e87-4cbf-a792-5dfb13457423', 'fe1b106c-18bc-4f85-943e-4950e0f3eb4f', 'tom');
|
||||
|
||||
INSERT INTO rooms (room_id, room_name)
|
||||
VALUES ('60nc0XXDIYUh6QzX4p0rMpCdzDmxghZLZk8dLuQh628', NULL);
|
||||
INSERT INTO room (room_id, room_name)
|
||||
VALUES ('24595934-4540-4333-ac2b-78796ac3f25f', 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');
|
||||
INSERT INTO member (member_id, domain_id, room_id, account_id)
|
||||
VALUES ('e735a9df-c55e-47d0-89d5-7a898162d6b9', 'fe1b106c-18bc-4f85-943e-4950e0f3eb4f',
|
||||
'24595934-4540-4333-ac2b-78796ac3f25f', '5c5dfc88-83f1-4933-b5cc-4a48eb735bfd'),
|
||||
('6527c20f-f956-4c86-84c5-d2835813bd06', 'fe1b106c-18bc-4f85-943e-4950e0f3eb4f',
|
||||
'24595934-4540-4333-ac2b-78796ac3f25f', '87fdbcb7-1e87-4cbf-a792-5dfb13457423');
|
||||
|
||||
|
||||
|
Reference in New Issue
Block a user