Files
profiles-plugin/data/profiles.sql

81 lines
3.3 KiB
PL/PgSQL

BEGIN;
-- User and Community Profiles {{{
INSERT INTO version_history (component, from_version, to_version, author) VALUES ('PROFILES', 0, 1, 'Initial Creation');
CREATE TABLE user_profiles(
profileid INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
nickname TEXT,
timezone TEXT,
locale_hint TEXT,
locale TEXT,
avatar TEXT,
migrated INTEGER REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_seen 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 TABLE profiles_discord(
linkid INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
profileid INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
userid BIGINT NOT NULL,
linked_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 PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
profileid INTEGER NOT NULL REFERENCES user_profiles (profileid) ON DELETE CASCADE ON UPDATE CASCADE,
userid TEXT NOT NULL,
linked_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 PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
migrated INTEGER REFERENCES communities (communityid) ON DELETE CASCADE ON UPDATE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_seen 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();
CREATE TABLE communities_discord(
linkid INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
guildid BIGINT NOT NULL,
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 UNIQUE INDEX communities_discord_guildid ON communities_discord (guildid);
CREATE TABLE communities_twitch(
linkid INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
channelid TEXT NOT NULL,
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 UNIQUE INDEX communities_twitch_channelid ON communities_twitch (channelid);
CREATE TABLE community_members(
memberid INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
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);
-- TODO: Consider 'networks' of multiple communities.
-- }}}
COMMIT;