BEGIN; INSERT INTO version_history (component, from_version, to_version, author) VALUES ('EVENT_TRACKER', 0, 1, 'Initial Creation'); -- TODO: Assert profiles data version -- Twitch tracked event data {{{ CREATE TABLE tracking_channels( userid TEXT PRIMARY KEY REFERENCES bot_channels(userid) ON DELETE CASCADE, joined BOOLEAN, joined_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), _timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TRIGGER tracking_channels_timestamp BEFORE UPDATE ON tracking_channels FOR EACH ROW EXECUTE FUNCTION update_timestamp_column(); CREATE TABLE events( event_id INTEGER GENERATED ALWAYS AS IDENTITY PRIMARY KEY, event_type TEXT NOT NULL, communityid INTEGER NOT NULL REFERENCES communities (communityid), channel_id TEXT NOT NULL, profileid INTEGER REFERENCES user_profiles (profileid), user_id TEXT, occurred_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (event_id, event_type) ); CREATE TABLE follow_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'follow' CHECK (event_type = 'follow'), follower_count INTEGER NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE bits_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'bits' CHECK (event_type = 'bits'), bits INTEGER NOT NULL, bits_type TEXT NOT NULL, message TEXT, powerup_type TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE subscribe_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'subscribe' CHECK (event_type = 'subscribe'), tier INTEGER NOT NULL, gifted BOOLEAN NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE gift_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'gift' CHECK (event_type = 'gift'), tier INTEGER NOT NULL, gifted_count INTEGER NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE subscribe_message_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'subscribe_message' CHECK (event_type = 'subscribe_message'), tier INTEGER NOT NULL, duration_months INTEGER NOT NULL, cumulative_months INTEGER NOT NULL, streak_months INTEGER, message TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE cheer_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'cheer' CHECK (event_type = 'cheer'), amount INTEGER NOT NULL, message TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE redemption_add_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'redemption_add' CHECK (event_type = 'redemption_add'), redeem_id TEXT NOT NULL, redeem_title TEXT NOT NULL, redeem_cost INTEGER NOT NULL, redemption_id TEXT NOT NULL, redemption_status TEXT NOT NULL, message TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE redemption_update_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'redemption_update' CHECK (event_type = 'redemption_update'), redeem_id TEXT NOT NULL, redeem_title TEXT NOT NULL, redeem_cost INTEGER NOT NULL, redemption_id TEXT NOT NULL, redemption_status TEXT NOT NULL, redeemed_at TIMESTAMPTZ NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE poll_end_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'poll_end' CHECK (event_type = 'poll_end'), poll_id TEXT NOT NULL, poll_title TEXT NOT NULL, poll_choices TEXT NOT NULL, poll_started TIMESTAMPTZ NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE stream_online_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'stream_online' CHECK (event_type = 'stream_online'), stream_id TEXT NOT NULL, stream_type TEXT NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE stream_offline_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'stream_offline' CHECK (event_type = 'stream_offline'), stream_id TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE channel_update_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'channel_update' CHECK (event_type = 'channel_update'), title TEXT, language TEXT, category_id TEXT, category_name TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE vip_add_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'vip_add' CHECK (event_type = 'vip_add'), FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE vip_remove_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'vip_remove' CHECK (event_type = 'vip_remove'), FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE message_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'message' CHECK (event_type = 'message'), message_id TEXT NOT NULL, message_type TEXT NOT NULL, content TEXT, source_channel_id TEXT, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE raid_out_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'raidout' CHECK (event_type = 'raidout'), target_id TEXT NOT NULL, target_name TEXT, viewer_count INTEGER NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); CREATE TABLE raid_in_events( event_id INTEGER PRIMARY KEY REFERENCES events (event_id), event_type TEXT NOT NULL DEFAULT 'raidin' CHECK (event_type = 'raidin'), source_id TEXT NOT NULL, source_name TEXT, viewer_count INTEGER NOT NULL, FOREIGN KEY (event_id, event_type) REFERENCES events (event_id, event_type) ); -- }}} COMMIT;