-- Add deleted to channels ( migrate existing as '0' ) -- Add deleted to keytokens ( migrate existing as '0' ) -- Add deleted to subscriptions ( migrate existing as '0' ) -- Add deleted to users ( migrate existing as '0' ) -- Add deleted to deliveries ( migrate existing as '0' ) -- -- Add active to subcsriptions ( migrate existing as '1' ) -- -- Add channel_owner_id to messages ( migrate existing by looking up channel ) -- ------------------------------------------------------------------------------------------------------------------------ DROP INDEX "idx_users_protoken"; CREATE TABLE __new_users ( user_id TEXT NOT NULL, username TEXT NULL DEFAULT NULL, timestamp_created INTEGER NOT NULL, timestamp_lastread INTEGER NULL DEFAULT NULL, timestamp_lastsent INTEGER NULL DEFAULT NULL, messages_sent INTEGER NOT NULL DEFAULT '0', quota_used INTEGER NOT NULL DEFAULT '0', quota_used_day TEXT NULL DEFAULT NULL, is_pro INTEGER CHECK(is_pro IN (0, 1)) NOT NULL DEFAULT 0, pro_token TEXT NULL DEFAULT NULL, deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0', PRIMARY KEY (user_id) ) STRICT; INSERT INTO __new_users SELECT user_id, username, timestamp_created, timestamp_lastread, timestamp_lastsent, messages_sent, quota_used, quota_used_day, is_pro, pro_token, 0 AS deleted FROM users; DROP TABLE users; ALTER TABLE __new_users RENAME TO users; CREATE UNIQUE INDEX "idx_users_protoken" ON users (pro_token) WHERE pro_token IS NOT NULL AND deleted=0; ------------------------------------------------------------------------------------------------------------------------ DROP INDEX "idx_keytokens_token"; CREATE TABLE __new_keytokens ( keytoken_id TEXT NOT NULL, timestamp_created INTEGER NOT NULL, timestamp_lastused INTEGER NULL DEFAULT NULL, name TEXT NOT NULL, owner_user_id TEXT NOT NULL, all_channels INTEGER CHECK(all_channels IN (0, 1)) NOT NULL, channels TEXT NOT NULL, token TEXT NOT NULL, permissions TEXT NOT NULL, messages_sent INTEGER NOT NULL DEFAULT '0', deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0', PRIMARY KEY (keytoken_id) ) STRICT; INSERT INTO __new_keytokens SELECT keytoken_id, timestamp_created, timestamp_lastused, name, owner_user_id, all_channels, channels, token, permissions, messages_sent, 0 AS deleted FROM keytokens; DROP TABLE keytokens; ALTER TABLE __new_keytokens RENAME TO keytokens; CREATE UNIQUE INDEX "idx_keytokens_token" ON keytokens (token); ------------------------------------------------------------------------------------------------------------------------ DROP INDEX "idx_deliveries_receiver"; CREATE TABLE __new_deliveries ( delivery_id TEXT NOT NULL, message_id TEXT NOT NULL, receiver_user_id TEXT NOT NULL, receiver_client_id TEXT NOT NULL, timestamp_created INTEGER NOT NULL, timestamp_finalized INTEGER NULL, status TEXT CHECK(status IN ('RETRY','SUCCESS','FAILED')) NOT NULL, retry_count INTEGER NOT NULL DEFAULT 0, next_delivery INTEGER NULL DEFAULT NULL, fcm_message_id TEXT NULL, deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0', PRIMARY KEY (delivery_id) ) STRICT; INSERT INTO __new_deliveries SELECT delivery_id, message_id, receiver_user_id, receiver_client_id, timestamp_created, timestamp_finalized, status, retry_count, next_delivery, fcm_message_id, 0 as deleted FROM deliveries; DROP TABLE deliveries; ALTER TABLE __new_deliveries RENAME TO deliveries; CREATE INDEX "idx_deliveries_receiver" ON deliveries (message_id, receiver_client_id); ------------------------------------------------------------------------------------------------------------------------ DROP INDEX "idx_messages_channel"; DROP INDEX "idx_messages_channel_nc"; DROP INDEX "idx_messages_idempotency"; DROP INDEX "idx_messages_senderip"; DROP INDEX "idx_messages_sendername"; DROP INDEX "idx_messages_sendername_nc"; DROP INDEX "idx_messages_title"; DROP INDEX "idx_messages_title_nc"; DROP INDEX "idx_messages_usedkey"; DROP INDEX "idx_messages_deleted"; CREATE TABLE __new_messages ( message_id TEXT NOT NULL, sender_user_id TEXT NOT NULL, channel_internal_name TEXT NOT NULL, channel_id TEXT NOT NULL, channel_owner_user_id TEXT NOT NULL, sender_ip TEXT NOT NULL, sender_name TEXT NULL, timestamp_real INTEGER NOT NULL, timestamp_client INTEGER NULL, title TEXT NOT NULL, content TEXT NULL, priority INTEGER CHECK(priority IN (0, 1, 2)) NOT NULL, usr_message_id TEXT NULL, used_key_id TEXT NOT NULL, deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0', PRIMARY KEY (message_id) ) STRICT; INSERT INTO __new_messages SELECT m.message_id, m.sender_user_id, m.channel_internal_name, m.channel_id, c.owner_user_id, m.sender_ip, m.sender_name, m.timestamp_real, m.timestamp_client, m.title, m.content, m.priority, m.usr_message_id, m.used_key_id, m.deleted FROM messages m JOIN channels c ON m.channel_id = c.channel_id; DROP TABLE messages; ALTER TABLE __new_messages RENAME TO messages; CREATE INDEX "idx_messages_channel" ON messages (channel_internal_name COLLATE BINARY); CREATE INDEX "idx_messages_channel_nc" ON messages (channel_internal_name COLLATE NOCASE); CREATE UNIQUE INDEX "idx_messages_idempotency" ON messages (sender_user_id, usr_message_id COLLATE BINARY); CREATE INDEX "idx_messages_senderip" ON messages (sender_ip COLLATE BINARY); CREATE INDEX "idx_messages_sendername" ON messages (sender_name COLLATE BINARY); CREATE INDEX "idx_messages_sendername_nc" ON messages (sender_name COLLATE NOCASE); CREATE INDEX "idx_messages_title" ON messages (title COLLATE BINARY); CREATE INDEX "idx_messages_title_nc" ON messages (title COLLATE NOCASE); CREATE INDEX "idx_messages_usedkey" ON messages (sender_user_id, used_key_id); CREATE INDEX "idx_messages_deleted" ON messages (deleted); DROP TRIGGER IF EXISTS fts_insert; DROP TRIGGER IF EXISTS fts_update; DROP TRIGGER IF EXISTS fts_delete; DROP TABLE IF EXISTS messages_fts; CREATE VIRTUAL TABLE messages_fts USING fts5 ( channel_internal_name, sender_name, title, content, tokenize = unicode61, content = 'messages', content_rowid = 'rowid' ); CREATE TRIGGER fts_insert AFTER INSERT ON messages BEGIN INSERT INTO messages_fts (rowid, channel_internal_name, sender_name, title, content) VALUES (new.rowid, new.channel_internal_name, new.sender_name, new.title, new.content); END; CREATE TRIGGER fts_update AFTER UPDATE ON messages BEGIN INSERT INTO messages_fts (messages_fts, rowid, channel_internal_name, sender_name, title, content) VALUES ('delete', old.rowid, old.channel_internal_name, old.sender_name, old.title, old.content); INSERT INTO messages_fts ( rowid, channel_internal_name, sender_name, title, content) VALUES ( new.rowid, new.channel_internal_name, new.sender_name, new.title, new.content); END; CREATE TRIGGER fts_delete AFTER DELETE ON messages BEGIN INSERT INTO messages_fts (messages_fts, rowid, channel_internal_name, sender_name, title, content) VALUES ('delete', old.rowid, old.channel_internal_name, old.sender_name, old.title, old.content); END; INSERT INTO messages_fts (rowid, channel_internal_name, sender_name, title, content) SELECT rowid, channel_internal_name, sender_name, title, content FROM messages; ------------------------------------------------------------------------------------------------------------------------ DROP INDEX "idx_channels_identity"; CREATE TABLE __new_channels ( channel_id TEXT NOT NULL, owner_user_id TEXT NOT NULL, internal_name TEXT NOT NULL, display_name TEXT NOT NULL, description_name TEXT NULL, subscribe_key TEXT NOT NULL, timestamp_created INTEGER NOT NULL, timestamp_lastsent INTEGER NULL DEFAULT NULL, messages_sent INTEGER NOT NULL DEFAULT '0', deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0', PRIMARY KEY (channel_id) ) STRICT; INSERT INTO __new_channels SELECT channel_id, owner_user_id, internal_name, display_name, description_name, subscribe_key, timestamp_created, timestamp_lastsent, messages_sent, 0 AS deleted FROM channels; DROP TABLE channels; ALTER TABLE __new_channels RENAME TO channels; CREATE UNIQUE INDEX "idx_channels_identity" ON channels (owner_user_id, internal_name) WHERE deleted=0; ------------------------------------------------------------------------------------------------------------------------ DROP INDEX "idx_subscriptions_ref"; DROP INDEX "idx_subscriptions_chan"; DROP INDEX "idx_subscriptions_subuser"; DROP INDEX "idx_subscriptions_ownuser"; DROP INDEX "idx_subscriptions_tsc"; DROP INDEX "idx_subscriptions_conf"; CREATE TABLE __new_subscriptions ( subscription_id TEXT NOT NULL, subscriber_user_id TEXT NOT NULL, channel_owner_user_id TEXT NOT NULL, channel_internal_name TEXT NOT NULL, channel_id TEXT NOT NULL, timestamp_created INTEGER NOT NULL, confirmed INTEGER CHECK(confirmed IN (0, 1)) NOT NULL, active INTEGER CHECK(active IN (0, 1)) NOT NULL, deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0', PRIMARY KEY (subscription_id) ) STRICT; INSERT INTO __new_subscriptions SELECT subscription_id, subscriber_user_id, channel_owner_user_id, channel_internal_name, channel_id, timestamp_created, confirmed, 1 AS active, 0 AS deleted FROM subscriptions; DROP TABLE subscriptions; ALTER TABLE __new_subscriptions RENAME TO subscriptions; CREATE UNIQUE INDEX "idx_subscriptions_ref" ON subscriptions (subscriber_user_id, channel_owner_user_id, channel_internal_name) WHERE deleted=0; CREATE INDEX "idx_subscriptions_chan" ON subscriptions (channel_id); CREATE INDEX "idx_subscriptions_subuser" ON subscriptions (subscriber_user_id); CREATE INDEX "idx_subscriptions_ownuser" ON subscriptions (channel_owner_user_id); CREATE INDEX "idx_subscriptions_tsc" ON subscriptions (timestamp_created); CREATE INDEX "idx_subscriptions_conf" ON subscriptions (confirmed); ------------------------------------------------------------------------------------------------------------------------