117 lines
3.4 KiB
PL/PgSQL
117 lines
3.4 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();
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
-- }}}
|
|
|
|
-- App metadata {{{
|
|
|
|
CREATE TABLE app_config(
|
|
appname TEXT PRIMARY KEY,
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- }}}
|
|
|
|
-- Twitch Auth {{{
|
|
|
|
-- Authorisation tokens allowing us to take actions on behalf of certain users or channels.
|
|
-- For example, channels we have joined will need to be authorised with a 'channel:bot' scope.
|
|
CREATE TABLE user_auth(
|
|
userid TEXT PRIMARY KEY,
|
|
token TEXT NOT NULL,
|
|
refresh_token TEXT NOT NULL,
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
_timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
CREATE TRIGGER user_auth_timestamp BEFORE UPDATE ON user_auth
|
|
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
|
|
|
|
CREATE TABLE user_auth_scopes(
|
|
userid TEXT NOT NULL REFERENCES user_auth(userid) ON DELETE CASCADE,
|
|
scope TEXT NOT NULL
|
|
);
|
|
|
|
-- Which joins will be joined at startup,
|
|
-- and any configurable choices needed when joining the channel
|
|
CREATE TABLE bot_channels(
|
|
userid TEXT PRIMARY KEY REFERENCES user_auth(userid) ON DELETE CASCADE,
|
|
autojoin BOOLEAN DEFAULT true,
|
|
listen_redeems BOOLEAN,
|
|
joined_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
_timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
CREATE TRIGGER bot_channels_timestamp BEFORE UPDATE ON bot_channels
|
|
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
|
|
|
|
|
|
-- }}}
|
|
|
|
-- Twitch user data {{{
|
|
|
|
---- Users are internally represented by 'profiles' with a unique profileid
|
|
---- This is associated to the user's twitch userid.
|
|
---- Any user-specific configuration data or preferences can be added here
|
|
CREATE TABLE user_profiles(
|
|
profileid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
|
|
twitchid TEXT NOT NULL,
|
|
name TEXT,
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
_timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
CREATE TRIGGER user_profiles_timestamp BEFORE UPDATE ON user_profiles
|
|
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
|
|
|
|
|
|
CREATE UNIQUE INDEX user_profile_twitchid ON user_profiles (twitchid);
|
|
|
|
-- }}}
|
|
|
|
-- Twitch channel data {{{
|
|
|
|
---- Similar to user profiles, we associate twitch channels with 'communities'
|
|
---- This slight abstraction gives us more flexibility and control over the community and user data.
|
|
CREATE TABLE communities(
|
|
communityid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
|
|
twitchid TEXT NOT NULL,
|
|
name TEXT,
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
_timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
CREATE TRIGGER communities_timestamp BEFORE UPDATE ON communities
|
|
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
|
|
|
|
-- }}}
|
|
|
|
|
|
-- Koan data {{{
|
|
|
|
---- !koans lists koans. !koan gives a random koan. !koans add name ... !koans del name ...
|
|
|
|
CREATE TABLE koans(
|
|
koanid INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
|
|
communityid INTEGER NOT NULL REFERENCES communities ON UPDATE CASCADE ON DELETE CASCADE,
|
|
name TEXT NOT NULL,
|
|
message TEXT NOT NULL,
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
_timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
CREATE TRIGGER koans_timestamp BEFORE UPDATE ON koans
|
|
FOR EACH ROW EXECUTE FUNCTION update_timestamp_column();
|
|
|
|
-- }}}
|
|
|
|
-- vim: set fdm=marker:
|