-- 19.02 CREATE TABLE mix_channel ( channel text NOT NULL, service text NOT NULL, username text NOT NULL, domain text NOT NULL, jid text NOT NULL, hidden boolean NOT NULL, hmac_key text NOT NULL, created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE UNIQUE INDEX i_mix_channel ON mix_channel (channel, service); CREATE INDEX i_mix_channel_serv ON mix_channel (service); CREATE TABLE mix_participant ( channel text NOT NULL, service text NOT NULL, username text NOT NULL, domain text NOT NULL, jid text NOT NULL, id text NOT NULL, nick text NOT NULL, created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE UNIQUE INDEX i_mix_participant ON mix_participant (channel, service, username, domain); CREATE INDEX i_mix_participant_chan_serv ON mix_participant (channel, service); CREATE TABLE mix_subscription ( channel text NOT NULL, service text NOT NULL, username text NOT NULL, domain text NOT NULL, node text NOT NULL, jid text NOT NULL ); CREATE UNIQUE INDEX i_mix_subscription ON mix_subscription (channel, service, username, domain, node); CREATE INDEX i_mix_subscription_chan_serv_ud ON mix_subscription (channel, service, username, domain); CREATE INDEX i_mix_subscription_chan_serv_node ON mix_subscription (channel, service, node); CREATE INDEX i_mix_subscription_chan_serv ON mix_subscription (channel, service); CREATE TABLE mix_pam ( username text NOT NULL, channel text NOT NULL, service text NOT NULL, id text NOT NULL, created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE UNIQUE INDEX i_mix_pam ON mix_pam (username, channel, service); CREATE INDEX i_mix_pam_us ON mix_pam (username); -- 20.01 CREATE TABLE oauth_client ( client_id text PRIMARY KEY, client_name text NOT NULL, grant_type text NOT NULL, options text NOT NULL ); -- 21.07 CREATE UNIQUE INDEX i_sr_group_name ON sr_group USING btree (name); -- 21.12 -- If you migrated your PostgreSQL database from old to new schema using -- previous ejabberd versions, your database may be missing the migration -- steps for the push_session table. You can update it now with: ALTER TABLE push_session ADD COLUMN server_host text NOT NULL DEFAULT ''; DROP INDEX i_push_usn; DROP INDEX i_push_ut; ALTER TABLE push_session ADD PRIMARY KEY (server_host, username, timestamp); CREATE UNIQUE INDEX i_push_session_susn ON push_session USING btree (server_host, username, service, node); -- In the PostgreSQL new schema, the primary key for the vcard_search table -- was wrong. How to update an existing database: ALTER TABLE vcard_search DROP CONSTRAINT vcard_search_pkey; ALTER TABLE vcard_search ADD PRIMARY KEY (server_host, lusername); -- 22.05 CREATE INDEX i_muc_room_host_created_at ON muc_room USING btree (host, created_at); CREATE INDEX i_muc_room_subscribers_jid ON muc_room_subscribers USING btree (jid); ALTER TABLE archive DROP CONSTRAINT i_archive_sh_peer; ALTER TABLE archive DROP CONSTRAINT i_archive_sh_bare_peer; CREATE INDEX i_archive_sh_username_peer ON archive USING btree (server_host, username, peer); CREATE INDEX i_archive_sh_username_bare_peer ON archive USING btree (server_host, username, bare_peer); DROP TABLE carboncopy; ALTER TABLE push_session DROP CONSTRAINT i_push_session_susn; CREATE UNIQUE INDEX i_push_session_susn ON push_session USING btree (server_host, username, service, node); ALTER TABLE mix_pam DROP CONSTRAINT i_mix_pam; ALTER TABLE mix_pam DROP CONSTRAINT i_mix_pam_us; CREATE UNIQUE INDEX i_mix_pam ON mix_pam (username, server_host, channel, service); CREATE INDEX i_mix_pam_us ON mix_pam (username, server_host); ALTER TABLE route DROP CONSTRAINT i_route; CREATE UNIQUE INDEX i_route ON route USING btree (domain, server_host, node, pid); ALTER TABLE mqtt_pub DROP CONSTRAINT i_mqtt_topic; CREATE UNIQUE INDEX i_mqtt_topic_server ON mqtt_pub (topic, server_host); -- 23.04 ALTER TABLE vcard_search DROP CONSTRAINT vcard_search_pkey; ALTER TABLE vcard_search ADD PRIMARY KEY (server_host, lusername); ALTER TABLE archive ALTER COLUMN id TYPE BIGINT; ALTER TABLE privacy_list ALTER COLUMN id TYPE BIGINT; ALTER TABLE pubsub_node ALTER COLUMN nodeid TYPE BIGINT; ALTER TABLE pubsub_state ALTER COLUMN stateid TYPE BIGINT; ALTER TABLE spool ALTER COLUMN seq TYPE BIGINT; DROP INDEX i_rosteru_username; DROP INDEX i_sr_user_jid; DROP INDEX i_privacy_list_username; DROP INDEX i_private_storage_username; DROP INDEX i_muc_online_users_us; DROP INDEX i_route_domain; DROP INDEX i_mix_participant_chan_serv; DROP INDEX i_mix_subscription_chan_serv_ud; DROP INDEX i_mix_subscription_chan_serv; DROP INDEX i_mix_pam_us; DROP INDEX i_rosteru_sh_username; DROP INDEX i_sr_user_sh_jid; DROP INDEX i_privacy_list_sh_username; DROP INDEX i_private_storage_sh_username; DROP INDEX i_muc_online_users_us; DROP INDEX i_route_domain; DROP INDEX i_mix_participant_chan_serv; DROP INDEX i_mix_subscription_chan_serv_ud; DROP INDEX i_mix_subscription_chan_serv; DROP INDEX i_mix_pam_us; CREATE INDEX i_push_session_sh_username_timestamp ON push_session USING btree (server_host, username, timestamp);