DROP DATABASE IF EXISTS locutus;
CREATE DATABASE locutus;

\c locutus

CREATE TABLE domain
(
    domain_id   UUID NOT NULL,
    domain_name TEXT NOT NULL,

    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 account
(
    account_id   UUID NOT NULL,
    domain_id    UUID NOT NULL,
    account_name TEXT NOT NULL,

    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 room
(
    room_id   UUID NOT NULL,
    room_name TEXT,

    CONSTRAINT pk_room PRIMARY KEY (room_id)
);

CREATE TABLE event
(
    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,
    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_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_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 member
(
    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_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 session
(
    session_id    UUID                        NOT NULL,
    account_id    UUID                        NOT NULL,
    session_nr    INTEGER                     NOT NULL DEFAULT 1,
    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'),
    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_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 domain (domain_id, domain_name)
VALUES ('fe1b106c-18bc-4f85-943e-4950e0f3eb4f', 'necronda.net');

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 room (room_id, room_name)
VALUES ('24595934-4540-4333-ac2b-78796ac3f25f', NULL);

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');