Files
lilacbot/data/schema.sql

110 lines
2.8 KiB
PL/PgSQL

-- Metadata {{{
CREATE TABLE VersionHistory(
version INTEGER NOT NULL,
time TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
author TEXT
);
INSERT INTO VersionHistory (version, author) VALUES (1, 'Initial Creation');
CREATE OR REPLACE FUNCTION update_timestamp_column()
RETURNS TRIGGER AS $$
BEGIN
NEW._timestamp = (now() at time zone 'utc');
RETURN NEW;
END;
$$ language 'plpgsql';
-- }}}
-- App metadata {{{
CREATE TABLE app_config(
appname TEXT PRIMARY KEY,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE bot_config(
appname TEXT PRIMARY KEY REFERENCES app_config(appname) ON DELETE CASCADE,
sponsor_prompt TEXT,
sponsor_message TEXT,
default_skin TEXT
);
-- }}}
-- Channel Linker {{{
CREATE TABLE links(
linkid SERIAL PRIMARY KEY,
name TEXT
);
CREATE TABLE channel_webhooks(
channelid BIGINT PRIMARY KEY,
webhookid BIGINT NOT NULL,
token TEXT NOT NULL
);
CREATE TABLE channel_links(
linkid INTEGER NOT NULL REFERENCES links (linkid) ON DELETE CASCADE,
channelid BIGINT NOT NULL REFERENCES channel_webhooks (channelid) ON DELETE CASCADE,
PRIMARY KEY (linkid, channelid)
);
-- }}}
-- Message Logging {{{
CREATE TABLE logging_guilds(
guildid BIGINT PRIMARY KEY,
webhook_url TEXT,
created_at TIMESTAMPTZ DEFAULT NOW(),
_timestamp TIMESTAMPTZ DEFAULT NOW()
);
CREATE TRIGGER logging_guilds_timestamp BEFORE UPDATE ON logging_guilds
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
CREATE TABLE logged_messages(
messageid BIGINT PRIMARY KEY,
guildid BIGINT NOT NULL REFERENCES logging_guilds ON DELETE CASCADE,
channelid BIGINT NOT NULL,
userid BIGINT NOT NULL,
created_at TIMESTAMPTZ NOT NULL,
deleted_at TIMESTAMPTZ,
_timestamp TIMESTAMPTZ DEFAULT NOW()
);
CREATE TRIGGER logged_messages_timestamp BEFORE UPDATE ON logged_messages
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
CREATE TABLE message_states(
stateid INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
messageid BIGINT NOT NULL REFERENCES logged_messages ON DELETE CASCADE,
content TEXT NOT NULL,
embeds_raw TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX message_states_messageid ON message_states (messageid);
CREATE TABLE logged_attachments(
attachment_id BIGINT PRIMARY KEY,
proxy_url TEXT NOT NULL,
url TEXT NOT NULL,
content_type TEXT NOT NULL,
filesize INTEGER NOT NULL,
filename TEXT NOT NULL,
permalink TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE logged_messages_attachments(
stateid INTEGER NOT NULL REFERENCES message_states(stateid) ON DELETE CASCADE,
attachment_id BIGINT NOT NULL REFERENCES logged_attachments(attachment_id) ON DELETE CASCADE
);
CREATE INDEX logged_messages_attachments_stateid ON logged_messages_attachments (stateid);
-- }}}
-- vim: set fdm=marker: