Files
adventures/data/schema.sql

317 lines
8.7 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
);
-- }}}
--------
-- User and Community Profiles {{{
DROP TABLE IF EXISTS community_members;
DROP TABLE IF EXISTS communities_twitch;
DROP TABLE IF EXISTS communities_discord;
DROP TABLE IF EXISTS communities;
DROP TABLE IF EXISTS profiles_twitch;
DROP TABLE IF EXISTS profiles_discord;
DROP TABLE IF EXISTS user_profiles;
CREATE TABLE user_profiles(
profileid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
nickname TEXT,
migrated INTEGER REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE profiles_discord(
linkid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
profileid INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
userid BIGINT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX profiles_discord_profileid ON profiles_discord (profileid);
CREATE UNIQUE INDEX profiles_discord_userid ON profiles_discord (userid);
CREATE TABLE profiles_twitch(
linkid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
profileid INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
userid TEXT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX profiles_twitch_profileid ON profiles_twitch (profileid);
CREATE UNIQUE INDEX profiles_twitch_userid ON profiles_twitch (userid);
CREATE TABLE communities(
communityid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
migrated INTEGER REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE communities_discord(
guildid BIGINT PRIMARY KEY,
communityid INTEGER NOT NULL REFERENCES communities (communityid) ON DELETE CASCADE ON UPDATE CASCADE,
linked_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX communities_discord_communityid ON communities_discord (communityid);
CREATE TABLE communities_twitch(
channelid TEXT PRIMARY KEY,
communityid INTEGER NOT NULL REFERENCES communities (communityid) ON DELETE CASCADE ON UPDATE CASCADE,
linked_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX communities_twitch_communityid ON communities_twitch (communityid);
CREATE TABLE community_members(
memberid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
communityid INTEGER NOT NULL REFERENCES communities (communityid) ON DELETE CASCADE ON UPDATE CASCADE,
profileid INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE UNIQUE INDEX community_members_communityid_profileid ON community_members (communityid, profileid);
-- }}}
-- Twitch User Auth {{{
CREATE TABLE twitch_user_auth(
userid TEXT PRIMARY KEY,
access_token TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
refresh_token TEXT NOT NULL,
obtained_at TIMESTAMPTZ
);
CREATE TABLE twitch_user_scopes(
userid TEXT REFERENCES twitch_user_auth (userid) ON DELETE CASCADE ON UPDATE CASCADE,
scope TEXT
);
CREATE INDEX twitch_user_scopes_userid ON twitch_user_scopes (userid);
-- }}}
---------
-- Users {{{
CREATE TABLE user_preferences (
profileid INTEGER PRIMARY KEY REFERENCES user_profiles (profileid) ON DELETE CASCADE,
twitch_name TEXT,
preferences TEXT
);
CREATE VIEW dreamers AS
SELECT
user_profiles.profileid AS user_id,
user_preferences.twitch_name AS name,
profiles_twitch.userid AS twitch_id,
user_preferences.preferences AS preferences,
user_profiles.created_at AS created_at
FROM
user_profiles
LEFT JOIN profiles_twitch USING (profileid)
LEFT JOIN user_preferences USING (profileid);
-- }}}
-- Inventory {{{
CREATE TABLE user_inventory (
item_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
owner_id INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE,
obtained_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
quantity INTEGER NOT NULL DEFAULT 1,
removed_at TIMESTAMPTZ
);
-- }}}
-- Wallet {{{
CREATE TABLE user_wallet (
transaction_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
user_id INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE,
amount INTEGER NOT NULL,
description TEXT NOT NULL,
reference TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE user_purchases (
purchase_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
transaction_id INTEGER NOT NULL REFERENCES user_wallet ON DELETE CASCADE,
item_id INTEGER NOT NULL REFERENCES user_inventory ON DELETE CASCADE
);
-- }}}
-- Stamps {{{
CREATE TABLE stamp_types (
stamp_type_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
stamp_type_name TEXT UNIQUE NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- }}}
-- Documents {{{
CREATE TABLE documents (
document_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
document_data VARCHAR NOT NULL,
seal INTEGER NOT NULL,
metadata TEXT
);
CREATE TABLE document_stamps (
stamp_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
document_id INTEGER NOT NULL REFERENCES documents (document_id) ON DELETE CASCADE,
stamp_type INTEGER NOT NULL REFERENCES stamp_types (stamp_type_id) ON DELETE CASCADE,
position_x INTEGER NOT NULL,
position_y INTEGER NOT NULL,
rotation REAL NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- }}}
-- Events {{{
CREATE TYPE EventType AS ENUM (
'subscriber',
'raid',
'cheer',
'plain'
);
CREATE TABLE events (
event_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
user_id INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE,
document_id INTEGER REFERENCES documents (document_id) ON DELETE SET NULL,
user_name TEXT,
event_type EventType NOT NULL,
occurred_at TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE (event_id, event_type)
);
CREATE TABLE plain_events (
event_id integer PRIMARY KEY,
event_type EventType NOT NULL DEFAULT 'plain' CHECK (event_type = 'plain'),
message TEXT NOT NULL,
FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type)
);
CREATE TABLE raid_events (
event_id integer PRIMARY KEY,
event_type EventType NOT NULL DEFAULT 'raid' CHECK (event_type = 'raid'),
visitor_count INTEGER NOT NULL,
FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type)
);
CREATE TABLE cheer_events (
event_id integer PRIMARY KEY,
event_type EventType NOT NULL DEFAULT 'cheer' CHECK (event_type = 'cheer'),
amount INTEGER NOT NULL,
cheer_type TEXT,
message TEXT,
FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type)
);
CREATE TABLE subscriber_events (
event_id integer PRIMARY KEY,
event_type EventType NOT NULL DEFAULT 'subscriber' CHECK (event_type = 'subscriber'),
subscribed_length INTEGER NOT NULL,
tier INTEGER NOT NULL,
message TEXT,
FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type)
);
CREATE VIEW event_details AS
SELECT
events.event_id AS event_id,
events.user_id AS user_id,
events.document_id AS document_id,
events.user_name AS user_name,
events.event_type AS event_type,
events.occurred_at AS occurred_at,
events.created_at AS created_at,
plain_events.message AS plain_message,
raid_events.visitor_count AS raid_visitor_count,
cheer_events.amount AS cheer_amount,
cheer_events.cheer_type AS cheer_type,
cheer_events.message AS cheer_message,
subscriber_events.subscribed_length AS subscriber_length,
subscriber_events.tier AS subscriber_tier,
subscriber_events.message AS subscriber_message,
FROM
events
LEFT JOIN plain_events USING (event_id)
LEFT JOIN raid_events USING (event_id)
LEFT JOIN cheer_events USING (event_id)
LEFT JOIN subscriber_events USING (event_id)
ORDER BY events.occurred_at ASC;
-- }}}
-- Specimens {{{
CREATE TABLE user_specimens (
specimen_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
owner_id INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE,
born_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
forgotten_at TIMESTAMPTZ
);
-- }}}
-- {{{
-- }}}
-- {{{
-- }}}
-- {{{
-- }}}
-- {{{
-- }}}
-- vim: set fdm=marker: