diff --git a/doc/migrations/4.2.0_4.3.0.md b/doc/migrations/4.2.0_4.3.0.md deleted file mode 100644 index a7efbcb28b5..00000000000 --- a/doc/migrations/4.2.0_4.3.0.md +++ /dev/null @@ -1,215 +0,0 @@ -## DB migrations - -### Inbox indexes - -Domain removal feature requires the order of fields to be changed: - -For Postgres: - -```sql --- Create a new index for the new primary key. -CREATE UNIQUE INDEX i_inbox_sur ON inbox (lserver, luser, remote_bare_jid); - --- Now enter a transaction block to replace the primary with the new one. -BEGIN; -ALTER TABLE inbox DROP CONSTRAINT inbox_pkey; -ALTER TABLE inbox ADD CONSTRAINT inbox_pkey PRIMARY KEY USING INDEX i_inbox_sur; -COMMIT; - -CREATE INDEX i_inbox_timestamp - ON inbox - USING BTREE(lserver, luser, timestamp); -DROP INDEX i_inbox; -``` - -For MySQL: - -```sql -BEGIN; -ALTER TABLE inbox DROP PRIMARY KEY; -ALTER TABLE inbox ADD PRIMARY KEY USING BTREE(lserver, luser, remote_bare_jid); -COMMIT; - -CREATE INDEX i_inbox_timestamp ON inbox(lserver, luser, timestamp); -DROP INDEX i_inbox ON inbox; -``` - -For MSSQL: - -```sql -CREATE INDEX i_inbox_su_ts ON inbox(lserver, luser, timestamp); -GO - -DROP INDEX i_inbox_ts ON inbox; -GO - -ALTER TABLE inbox DROP CONSTRAINT PK_inbox; -GO - -ALTER TABLE inbox ADD CONSTRAINT PK_inbox PRIMARY KEY CLUSTERED( - lserver ASC, luser ASC, remote_bare_jid ASC); -GO -``` - -### MUC-light indexes - -Order of fields in `i_muc_light_blocking` has changed. - -For Postgres: - -```sql -CREATE INDEX i_muc_light_blocking_su ON muc_light_blocking (lserver, luser); -DROP INDEX i_muc_light_blocking; -``` - -For MySQL: - -```sql -CREATE INDEX i_muc_light_blocking_su USING BTREE ON muc_light_blocking (lserver, luser); -DROP INDEX i_muc_light_blocking ON muc_light_blocking;; -``` - -For MSSQL: - -```sql -CREATE INDEX i_muc_light_blocking_su ON muc_light_blocking (lserver, luser); -GO - -DROP INDEX i_muc_light_blocking ON muc_light_blocking; -GO -``` - -### mod_privacy - -Server fields are added to privacy data, as well as their primary key having been expanded: - -For Postgres: - -```sql --- Create a new index for the new primary key. -CREATE UNIQUE INDEX i_privacy_default_list_su ON privacy_default_list (server, username); -CREATE UNIQUE INDEX i_privacy_list_sun ON privacy_list (server, username, name); - --- Now enter a transaction block to replace the primary with the new one. -BEGIN; -ALTER TABLE privacy_default_list ADD COLUMN server varchar(250); -ALTER TABLE privacy_default_list DROP CONSTRAINT privacy_default_list_pkey; -ALTER TABLE privacy_default_list ADD CONSTRAINT privacy_default_list_pkey PRIMARY KEY USING INDEX i_privacy_default_list_su; - -ALTER TABLE privacy_list ADD COLUMN server varchar(250) NOT NULL; -ALTER TABLE privacy_list DROP CONSTRAINT privacy_list_pkey; -ALTER TABLE privacy_list ADD CONSTRAINT privacy_list_pkey PRIMARY KEY USING INDEX i_privacy_list_sun; -COMMIT; -``` - -For MySQL: - -```sql -BEGIN; -ALTER TABLE privacy_default_list ADD COLUMN server varchar(250); -ALTER TABLE privacy_default_list DROP PRIMARY KEY; -ALTER TABLE privacy_default_list ADD PRIMARY KEY USING BTREE(server, username); - -ALTER TABLE privacy_list ADD COLUMN server varchar(250) NOT NULL; -ALTER TABLE privacy_list DROP PRIMARY KEY; -ALTER TABLE privacy_list ADD PRIMARY KEY USING BTREE(server, username, name); -COMMIT; -``` - -For MSSQL: - -```sql -ALTER TABLE privacy_default_list ADD COLUMN server varchar(250); -ALTER TABLE privacy_default_list DROP CONSTRAINT PK_privacy_default_list; -ALTER TABLE privacy_default_list ADD CONSTRAINT PK_privacy_default_list PRIMARY KEY CLUSTERED( - server ASC, username ASC); -GO - -ALTER TABLE privacy_list ADD COLUMN server varchar(250); -ALTER TABLE privacy_list DROP CONSTRAINT PK_privacy_list; -ALTER TABLE privacy_list ADD CONSTRAINT PK_privacy_list PRIMARY KEY CLUSTERED( - server ASC, username ASC, name ASC); -GO -``` - - -### mod_private - -For Postgres: - -```sql -ALTER TABLE private_storage ADD server varchar(250); - --- Assign some server to the old entries -UPDATE private_storage SET server = "localhost"; -ALTER TABLE private_storage ALTER COLUMN server SET NOT NULL; - -CREATE UNIQUE INDEX i_private_storage_sun ON private_storage USING btree (server, username, namespace); - -DROP INDEX i_private_storage_username; -DROP INDEX i_private_storage_username_namespace; - -ALTER TABLE private_storage ADD CONSTRAINT private_storage_pkey PRIMARY KEY USING INDEX i_private_storage_sun; -``` - -For MySQL: - -```sql -ALTER TABLE private_storage ADD server varchar(250); - --- Assign some server to the old entries -UPDATE private_storage SET server = "localhost"; -ALTER TABLE private_storage MODIFY COLUMN server varchar(150) NOT NULL; - -CREATE UNIQUE INDEX i_private_storage_sun ON private_storage (server, username, namespace); - -DROP INDEX i_private_storage_username ON private_storage; -DROP INDEX i_private_storage_username_namespace ON private_storage; - -ALTER TABLE private_storage ADD PRIMARY KEY USING BTREE(server, username, namespace); -``` - -For MSSQL: - -```sql -ALTER TABLE private_storage ADD server [nvarchar](150); --- Assign some server to the old entries -UPDATE private_storage SET server = 'localhost'; -ALTER TABLE private_storage ALTER COLUMN server [nvarchar](150) NOT NULL; -ALTER TABLE private_storage DROP CONSTRAINT private_storage$i_private_storage_username_namespace; -ALTER TABLE private_storage ADD CONSTRAINT PK_private_storage PRIMARY KEY CLUSTERED (server, username, namespace); -``` - -## Hook migrations - -- `filter_room_packet` hook uses a map instead of a proplist - for the event data information. -- `room_send_packet` hook has been removed. Use `filter_room_packet` instead. -- `filter_room_packet` is called for HostType (was for MucHost). -- `forget_room` is called for HostType (was for MucHost). -- `forget_room` takes an extra argument HostType. -- `filter_room_packet` takes an extra argument HostType. -- `is_muc_room_owner` is called for HostType (was for MucHost). -- `is_muc_room_owner` takes an extra argument HostType. -- `muc_room_pid` hook removed. -- `load_permanent_rooms_at_startup` option is ignored now. -- `gen_mod:get_module_opt_by_subhost` API removed. -- `update_inbox_for_muc` is called for HostType. -- `get_mam_muc_gdpr_data` is called for HostType. -- `get_mam_pm_gdpr_data` is called for HostType. -- `get_personal_data` handlers take an extra argument: `HostType` as the second parameter. -- `get_mam_pm_gdpr_data` and `get_mam_muc_gdpr_data` take `HostType` argument. - -## Metrics REST API (obsolete) - -The API is still considered obsolete so if you are using it, -please consider using [WombatOAM](https://www.erlang-solutions.com/capabilities/wombatoam/) -or metrics reporters as described in [Logging and monitoring](../operation-and-maintenance/Logging-&-monitoring.md). - -In each endpoint, `host` has been changed to `host_type`. -This is because the metrics are now collected per host type rather than host. - - -## Users cache - -MongooseIM used to feature a cache to check whether a user exists, that was unavoidably enabled, and had no eviction policy, that is, the cache could continue growing forever. Now, MIM features a module called [`mod_cache_users`](../modules/mod_cache_users) that implements a configurable cache policy, that can be enabled, disabled, and parametrised, per `host_type`. This might not be enabled by default in your configuration, so we recommend you verify your configuration and enable it if needed. diff --git a/doc/migrations/4.2.0_5.0.0.md b/doc/migrations/4.2.0_5.0.0.md new file mode 100644 index 00000000000..e2444719456 --- /dev/null +++ b/doc/migrations/4.2.0_5.0.0.md @@ -0,0 +1,57 @@ +## DB migrations + +The migrations scripts for Postgres, MySQL, MSSQL can be found in the [`priv/migrations`](../../priv/migrations/) directory. Please remember to provide the existing server domain for the `server` column instead of the localhost. + +### Changes in XEPs: +- `mod_last` + - Table `last` - added server column, updated primary key and indexes. +- `mod_privacy` + - Table `privacy_default_list` - added server column, updated primary key and indexes. + - Table `privacy_list` - added server column, updated primary key and indexes. +- `mod_private` + - Table `private_storage` - added server column, updated primary key and indexes, removed unused columns. +- `mod_roster` + - Table `rosterusers` - added server column, updated indexes. + - Table `rostergroups` - added server column, updated indexes. + - Table `roster_version` - added server column, updated primary key and indexes. +- `mod_muc` + - Table `i_muc_light_blocking` - updated indexes. +- `mod_inbox` + - Table `inbox` - updated primary key and indexes. + +### Other changes: +- RDBMS auth - modified `users` table. +- Added `domain_settings` table. +- Added `domain_events` table. + +## Hook migrations + +- `filter_room_packet` hook uses a map instead of a proplist for the event data information. +- `room_send_packet` hook has been removed. Use `filter_room_packet` instead. +- `filter_room_packet` is called for HostType (was for MucHost). +- `forget_room` is called for HostType (was for MucHost). +- `forget_room` takes an extra argument HostType. +- `filter_room_packet` takes an extra argument HostType. +- `is_muc_room_owner` is called for HostType (was for MucHost). +- `is_muc_room_owner` takes an extra argument HostType. +- `muc_room_pid` hook removed. +- `load_permanent_rooms_at_startup` option is ignored now. +- `gen_mod:get_module_opt_by_subhost` API removed. +- `update_inbox_for_muc` is called for HostType. +- `get_mam_muc_gdpr_data` is called for HostType. +- `get_mam_pm_gdpr_data` is called for HostType. +- `get_personal_data` handlers take an extra argument: `HostType` as the second parameter. +- `get_mam_pm_gdpr_data` and `get_mam_muc_gdpr_data` take `HostType` argument. + +## Metrics REST API (obsolete) + +The API is still considered obsolete so if you are using it, +please consider using [WombatOAM](https://www.erlang-solutions.com/capabilities/wombatoam/) +or metrics reporters as described in [Logging and monitoring](../operation-and-maintenance/Logging-&-monitoring.md). + +In each endpoint, `host` has been changed to `host_type`. +This is because the metrics are now collected per host type rather than host. + +## Users cache + +MongooseIM used to feature a cache to check whether a user exists, that was unavoidably enabled, and had no eviction policy, that is, the cache could continue growing forever. Now, MIM features a module called [`mod_cache_users`](../modules/mod_cache_users) that implements a configurable cache policy, that can be enabled, disabled, and parametrised, per `host_type`. This might not be enabled by default in your configuration, so we recommend you verify your configuration and enable it if needed. diff --git a/mkdocs.yml b/mkdocs.yml index 6b1c11a85f8..1c96c3145e8 100644 --- a/mkdocs.yml +++ b/mkdocs.yml @@ -63,7 +63,7 @@ nav: - '4.0.0 to 4.0.1': 'migrations/4.0.0_4.0.1.md' - '4.0.1 to 4.1.0': 'migrations/4.0.1_4.1.0.md' - '4.1.0 to 4.2.0': 'migrations/4.1.0_4.2.0.md' - - '4.2.0 to 4.3.0': 'migrations/4.2.0_4.3.0.md' + - '4.2.0 to 5.0.0': 'migrations/4.2.0_5.0.0.md' - 'MAM MUC migration helper': 'migrations/jid-from-mam-muc-script.md' - Platform: - 'Contributions to ecosystem': 'Contributions.md' diff --git a/priv/migrations/mssql_4.2.0_5.0.0.sql b/priv/migrations/mssql_4.2.0_5.0.0.sql new file mode 100644 index 00000000000..28b23a516ed --- /dev/null +++ b/priv/migrations/mssql_4.2.0_5.0.0.sql @@ -0,0 +1,136 @@ +-- MOD_LAST + +ALTER TABLE last ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE last SET server = 'localhost'; +ALTER TABLE last ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE last DROP CONSTRAINT PK_last_username; +ALTER TABLE last ADD CONSTRAINT PK_last_username PRIMARY KEY CLUSTERED (server ASC, username ASC); +COMMIT; + +CREATE INDEX i_last_server_seconds ON last (server, seconds); + +-- MOD_PRIVACY + +--Table privacy_default_list +ALTER TABLE privacy_default_list ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE privacy_default_list SET server = 'localhost'; +ALTER TABLE privacy_default_list ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE privacy_default_list DROP CONSTRAINT PK_privacy_default_list_username; +ALTER TABLE privacy_default_list ADD CONSTRAINT PK_privacy_default_list_username PRIMARY KEY CLUSTERED (server ASC, username ASC); +COMMIT; + +--Table privacy_list +ALTER TABLE privacy_list ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE privacy_list SET server = 'localhost'; +ALTER TABLE privacy_list ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE privacy_list DROP CONSTRAINT privacy_list$id; +ALTER TABLE privacy_list ADD CONSTRAINT PK_privacy_list PRIMARY KEY CLUSTERED (server ASC, username ASC, name ASC); +COMMIT; + +-- MOD_PRIVATE + +ALTER TABLE private_storage ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE private_storage SET server = 'localhost'; +ALTER TABLE private_storage ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE private_storage DROP CONSTRAINT private_storage$i_private_storage_username_namespace; +ALTER TABLE private_storage ADD CONSTRAINT PK_private_storage PRIMARY KEY CLUSTERED (server ASC, username ASC, namespace ASC); +COMMIT; + +-- MOD_ROSTER + +--Table rosterusers +ALTER TABLE rosterusers DROP COLUMN type; +ALTER TABLE rosterusers DROP COLUMN subscribe; +ALTER TABLE rosterusers DROP COLUMN server; + +ALTER TABLE rosterusers ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE rosterusers SET server = 'localhost'; +ALTER TABLE rosterusers ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE rosterusers DROP CONSTRAINT rosterusers$i_rosteru_user_jid; +ALTER TABLE rosterusers ADD CONSTRAINT rosterusers$i_rosteru_server_user_jid UNIQUE CLUSTERED (server ASC, username ASC, jid ASC); +COMMIT; + +CREATE INDEX i_rosteru_server_user ON rosterusers (server, username) +CREATE INDEX i_rosteru_jid ON rosterusers (jid) + +--Table rostergroups +ALTER TABLE rostergroups ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE rostergroups SET server = 'localhost'; +ALTER TABLE rostergroups ALTER COLUMN server [nvarchar](250) NOT NULL; + +CREATE INDEX i_rosterg_server_user_jid ON rostergroups (server, username, jid); + +--Table roster_version +ALTER TABLE roster_version ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE roster_version SET server = 'localhost'; +ALTER TABLE roster_version ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE roster_version DROP CONSTRAINT PK_roster_version_username; +ALTER TABLE roster_version ADD CONSTRAINT PK_roster_version_server_user PRIMARY KEY CLUSTERED (server ASC, username ASC); +COMMIT; + +-- MOD_MUC_LIGHT + +CREATE INDEX i_muc_light_blocking_su ON muc_light_blocking (lserver, luser); +DROP INDEX i_muc_light_blocking ON muc_light_blocking; + +-- MOD_INBOX + +CREATE INDEX i_inbox_su_ts ON inbox(lserver, luser, timestamp); +DROP INDEX i_inbox_ts ON inbox; + +BEGIN TRANSACTION; +ALTER TABLE inbox DROP CONSTRAINT PK_inbox; +ALTER TABLE inbox ADD CONSTRAINT PK_inbox PRIMARY KEY CLUSTERED (lserver ASC, luser ASC, remote_bare_jid ASC); +COMMIT; + +-- OTHER CHANGES + +--Table users +ALTER TABLE users ADD server [nvarchar](250); +-- FIXME Replace localhost with your domain name +UPDATE users SET server = 'localhost'; +ALTER TABLE users ALTER COLUMN server [nvarchar](250) NOT NULL; + +BEGIN TRANSACTION; +ALTER TABLE users DROP CONSTRAINT PK_users_username; +ALTER TABLE users ADD CONSTRAINT PK_users_username PRIMARY KEY CLUSTERED (server ASC, username ASC); +COMMIT; + +-- Table domain_settings +-- Mapping from domain hostname to host_type. +-- Column id is used for ordering only. +CREATE TABLE domain_settings ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + domain VARCHAR(250) NOT NULL, + host_type VARCHAR(250) NOT NULL, + enabled SMALLINT NOT NULL DEFAULT 1 +); + +-- Table domain_events +-- A new record is inserted into domain_events, each time +-- domain_settings table is updated. +-- Column id is used for ordering and not related to domain_settings.id. +CREATE TABLE domain_events ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + domain VARCHAR(250) NOT NULL +); +CREATE INDEX i_domain_events_domain ON domain_events(domain); diff --git a/priv/migrations/mysql_4.2.0_5.0.0.sql b/priv/migrations/mysql_4.2.0_5.0.0.sql new file mode 100644 index 00000000000..0b787f9ab92 --- /dev/null +++ b/priv/migrations/mysql_4.2.0_5.0.0.sql @@ -0,0 +1,105 @@ +-- MOD_LAST + +ALTER TABLE last ADD server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE last SET server = 'localhost'; + +ALTER TABLE last DROP PRIMARY KEY, ADD PRIMARY KEY(server, username); + +CREATE INDEX i_last_server_seconds ON last (server, seconds); +DROP INDEX i_last_seconds ON last; + +-- MOD_PRIVACY + +-- Table privacy_default_list +ALTER TABLE privacy_default_list ADD COLUMN server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE privacy_default_list SET server = 'localhost'; + +ALTER TABLE privacy_default_list DROP PRIMARY KEY, ADD PRIMARY KEY (server, username); + +-- Table privacy_list +ALTER TABLE privacy_list ADD COLUMN server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE privacy_list SET server = 'localhost'; + +ALTER TABLE privacy_list DROP PRIMARY KEY, ADD PRIMARY KEY (server, username, name); + +-- MOD_PRIVATE + +ALTER TABLE private_storage ADD server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE private_storage SET server = 'localhost'; + +ALTER TABLE private_storage ADD PRIMARY KEY (server, username, namespace); + +DROP INDEX i_private_storage_username ON private_storage; +DROP INDEX i_private_storage_username_namespace ON private_storage; + +-- MOD_ROSTER + +-- Table rosterusers +ALTER TABLE rosterusers DROP COLUMN `type`, DROP COLUMN subscribe, DROP COLUMN server; + +ALTER TABLE rosterusers ADD server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE rosterusers SET server = 'localhost'; + +CREATE UNIQUE INDEX i_rosteru_server_user_jid ON rosterusers (server, username, jid); +CREATE INDEX i_rosteru_server_user ON rosterusers (server, username); +DROP INDEX i_rosteru_user_jid ON rosterusers; +DROP INDEX i_rosteru_username ON rosterusers; + +-- Table rostergroups +ALTER TABLE rostergroups ADD server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE rostergroups SET server = 'localhost'; + +CREATE INDEX i_rosterg_server_user_jid ON rostergroups (server, username, jid); +DROP INDEX pk_rosterg_user_jid ON rostergroups; + +-- Table roster_version +ALTER TABLE roster_version ADD server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE roster_version SET server = 'localhost'; + +ALTER TABLE roster_version DROP PRIMARY KEY, ADD PRIMARY KEY (server, username); + +-- MOD_MUC_LIGHT +CREATE INDEX i_muc_light_blocking_su USING BTREE ON muc_light_blocking (lserver, luser); +DROP INDEX i_muc_light_blocking ON muc_light_blocking; + +-- MOD_INBOX +ALTER TABLE inbox DROP PRIMARY KEY, ADD PRIMARY KEY (lserver, luser, remote_bare_jid); + +DROP INDEX i_inbox ON inbox; +CREATE INDEX i_inbox ON inbox(lserver, luser, timestamp); + +-- OTHER CHANGES + +-- Table users +ALTER TABLE users ADD server varchar(250) NOT NULL; +-- FIXME Replace localhost with your domain name +UPDATE users SET server = 'localhost'; + +ALTER TABLE users DROP PRIMARY KEY, ADD PRIMARY KEY (server, username); + +-- Table domain_settings +-- Mapping from domain hostname to host_type. +-- Column id is used for ordering only. +CREATE TABLE domain_settings ( + id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, + domain VARCHAR(250) NOT NULL, + host_type VARCHAR(250) NOT NULL, + enabled BOOLEAN NOT NULL DEFAULT true +); + +-- Table domain_events +-- A new record is inserted into domain_events, each time +-- domain_settings table is updated. +-- Column id is used for ordering and not related to domain_settings.id. +CREATE TABLE domain_events ( + id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, + domain VARCHAR(250) NOT NULL +); +CREATE INDEX i_domain_events_domain ON domain_events(domain); diff --git a/priv/migrations/pgsql_4.2.0_5.0.0.sql b/priv/migrations/pgsql_4.2.0_5.0.0.sql new file mode 100644 index 00000000000..ca5ae2a6612 --- /dev/null +++ b/priv/migrations/pgsql_4.2.0_5.0.0.sql @@ -0,0 +1,119 @@ +-- MOD_LAST + +ALTER TABLE last ADD COLUMN server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE last SET server = 'localhost'; +ALTER TABLE last ALTER COLUMN server SET NOT NULL; + +ALTER TABLE last DROP CONSTRAINT last_pkey, ADD PRIMARY KEY (server, username); + +CREATE INDEX i_last_server_seconds ON last (server, seconds); +DROP INDEX i_last_seconds; + +-- MOD_PRIVACY + +-- Table privacy_default_list +ALTER TABLE privacy_default_list ADD COLUMN server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE privacy_default_list SET server = 'localhost'; +ALTER TABLE privacy_default_list ALTER COLUMN server SET NOT NULL; + +ALTER TABLE privacy_default_list DROP CONSTRAINT privacy_default_list_pkey, ADD PRIMARY KEY (server, username); + +-- Table privacy_list +ALTER TABLE privacy_list ADD COLUMN server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE privacy_list SET server = 'localhost'; +ALTER TABLE privacy_list ALTER COLUMN server SET NOT NULL; + +ALTER TABLE privacy_list DROP CONSTRAINT privacy_list_pkey, ADD PRIMARY KEY (server, username, name); + +-- MOD_PRIVATE + +-- Table private_storage +ALTER TABLE private_storage ADD server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE private_storage SET server = 'localhost'; +ALTER TABLE private_storage ALTER COLUMN server SET NOT NULL; + +ALTER TABLE private_storage ADD PRIMARY KEY (server, username, namespace); + +DROP INDEX i_private_storage_username; +DROP INDEX i_private_storage_username_namespace; + +-- MOD_ROSTER + +--Table rosterusers +ALTER TABLE rosterusers DROP COLUMN "type", DROP COLUMN subscribe, DROP COLUMN server; + +ALTER TABLE rosterusers ADD COLUMN server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE rosterusers SET server = 'localhost'; +ALTER TABLE rosterusers ALTER COLUMN server SET NOT NULL; + +CREATE UNIQUE INDEX i_rosteru_server_user_jid ON rosterusers (server, username, jid); +CREATE INDEX i_rosteru_server_user ON rosterusers (server, username); + +DROP INDEX i_rosteru_user_jid; +DROP INDEX i_rosteru_username; + +--Table rostergroups +ALTER TABLE rostergroups ADD COLUMN server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE rostergroups SET server = 'localhost'; +ALTER TABLE rostergroups ALTER COLUMN server SET NOT NULL; + +CREATE INDEX i_rosterg_server_user_jid ON rostergroups (server, username, jid); +DROP INDEX pk_rosterg_user_jid; + +-- Table roster_version +ALTER TABLE roster_version ADD server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE roster_version SET server = 'localhost'; +ALTER TABLE roster_version ALTER COLUMN server SET NOT NULL; + +ALTER TABLE roster_version DROP CONSTRAINT roster_version_pkey, ADD PRIMARY KEY (server, username); + +-- MOD_MUC_LIGHT + +CREATE INDEX i_muc_light_blocking_su ON muc_light_blocking (lserver, luser); +DROP INDEX i_muc_light_blocking; + +-- MOD_INBOX + +ALTER TABLE inbox DROP CONSTRAINT inbox_pkey, ADD PRIMARY KEY (lserver, luser, remote_bare_jid); +CREATE INDEX i_inbox_timestamp ON inbox USING BTREE (lserver, luser, timestamp); +DROP INDEX i_inbox; + +-- OTHER CHANGES + +-- Table users +ALTER TABLE users ADD COLUMN server varchar(250); +-- FIXME Replace localhost with your domain name +UPDATE users SET server = 'localhost'; +ALTER TABLE users ALTER COLUMN server SET NOT NULL; + +ALTER TABLE users DROP CONSTRAINT users_pkey, ADD PRIMARY KEY (server, username); + +-- Table domain_settings +-- Mapping from domain hostname to host_type. +-- Column id is used for ordering only. +CREATE TABLE domain_settings ( + id BIGSERIAL NOT NULL UNIQUE, + domain VARCHAR(250) NOT NULL, + host_type VARCHAR(250) NOT NULL, + enabled BOOLEAN NOT NULL DEFAULT true, + PRIMARY KEY(domain) +); + +-- Table domain_events +-- A new record is inserted into domain_events, each time +-- domain_settings table is updated: i.e. when a domain is removed, +-- inserted, enabled or disabled. +-- Column id is used for ordering and not related to domain_settings.id. +CREATE TABLE domain_events ( + id BIGSERIAL NOT NULL, + domain VARCHAR(250) NOT NULL, + PRIMARY KEY(id) +); +CREATE INDEX i_domain_events_domain ON domain_events(domain); diff --git a/priv/mssql2012.sql b/priv/mssql2012.sql index 732e121b58c..df8bf99e0d3 100644 --- a/priv/mssql2012.sql +++ b/priv/mssql2012.sql @@ -212,9 +212,11 @@ CREATE TABLE [dbo].[privacy_list]( [name] [nvarchar](250) NOT NULL, [id] [bigint] IDENTITY(1,1) NOT NULL, [created_at] [datetime] NOT NULL, - CONSTRAINT [privacy_list$id] UNIQUE CLUSTERED + CONSTRAINT [PK_privacy_list] PRIMARY KEY CLUSTERED ( - [id] ASC + [server] ASC, + [username] ASC, + [name] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY]