From a884860cdd9f442da2106a5d485380e4591d7714 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Przemys=C5=82aw=20Wojtasik?= Date: Tue, 31 Aug 2021 14:08:37 +0200 Subject: [PATCH] Improve scripts --- doc/migrations/4.2.0_5.0.0.md | 2 +- priv/migrations/mssql_4.2.0_5.0.0.sql | 42 ++++-------- priv/migrations/mysql_4.2.0_5.0.0.sql | 79 +++++---------------- priv/migrations/pgsql_4.2.0_5.0.0.sql | 98 ++++++--------------------- priv/mssql2012.sql | 4 +- 5 files changed, 55 insertions(+), 170 deletions(-) diff --git a/doc/migrations/4.2.0_5.0.0.md b/doc/migrations/4.2.0_5.0.0.md index c06795d8643..90f10ab209b 100644 --- a/doc/migrations/4.2.0_5.0.0.md +++ b/doc/migrations/4.2.0_5.0.0.md @@ -1,6 +1,6 @@ ## DB migrations -The migrations scripts for Postgres, MySQL, MSSQL can be found in the [`priv/migrations`](../../priv/migrations/) directory. +The migrations scripts for Postgres, MySQL, MSSQL can be found in the [`priv/migrations`](../../priv/migrations/) directory. Provide the existing server domain as a default for the `server` column instead of the empty string. ### Changes in XEPs: - `mod_last` diff --git a/priv/migrations/mssql_4.2.0_5.0.0.sql b/priv/migrations/mssql_4.2.0_5.0.0.sql index 112ba844a59..651887ebfbc 100644 --- a/priv/migrations/mssql_4.2.0_5.0.0.sql +++ b/priv/migrations/mssql_4.2.0_5.0.0.sql @@ -1,8 +1,6 @@ -- MOD_LAST -ALTER TABLE last ADD server [nvarchar](250); -UPDATE last SET server = 'localhost'; -ALTER TABLE last ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE last ADD server [nvarchar](250) NOT NULL DEFAULT ''; BEGIN TRANSACTION; ALTER TABLE last DROP CONSTRAINT PK_last_username; @@ -14,31 +12,24 @@ 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); -UPDATE privacy_default_list SET server = 'localhost'; -ALTER TABLE privacy_default_list ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE privacy_default_list ADD server [nvarchar](250) NOT NULL DEFAULT ''; 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); +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); -UPDATE privacy_list SET server = 'localhost'; -ALTER TABLE privacy_list ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE privacy_list ADD server [nvarchar](250) NOT NULL DEFAULT ''; 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); +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); -UPDATE private_storage SET server = 'localhost'; -ALTER TABLE private_storage ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE private_storage ADD server [nvarchar](250) NOT NULL DEFAULT ''; BEGIN TRANSACTION; ALTER TABLE private_storage DROP CONSTRAINT private_storage$i_private_storage_username_namespace; @@ -52,9 +43,7 @@ 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); -UPDATE rosterusers SET server = 'localhost'; -ALTER TABLE rosterusers ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE rosterusers ADD server [nvarchar](250) NOT NULL DEFAULT ''; BEGIN TRANSACTION; ALTER TABLE rosterusers DROP CONSTRAINT rosterusers$i_rosteru_user_jid; @@ -65,23 +54,19 @@ 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); -UPDATE rostergroups SET server = 'localhost'; -ALTER TABLE rostergroups ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE rostergroups ADD server [nvarchar](250) NOT NULL DEFAULT ''; CREATE INDEX i_rosterg_server_user_jid ON rostergroups (server, username, jid); --Table roster_version -ALTER TABLE roster_version ADD server [nvarchar](250); -UPDATE roster_version SET server = 'localhost'; -ALTER TABLE roster_version ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE roster_version ADD server [nvarchar](250) NOT NULL DEFAULT ''; 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 +-- 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; @@ -93,16 +78,13 @@ 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); +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); -UPDATE users SET server = 'localhost'; -ALTER TABLE users ALTER COLUMN server [nvarchar](250) NOT NULL; +ALTER TABLE users ADD server [nvarchar](250) NOT NULL DEFAULT ''; BEGIN TRANSACTION; ALTER TABLE users DROP CONSTRAINT PK_users_username; diff --git a/priv/migrations/mysql_4.2.0_5.0.0.sql b/priv/migrations/mysql_4.2.0_5.0.0.sql index 4047cbb5150..4b7ae6cfc56 100644 --- a/priv/migrations/mysql_4.2.0_5.0.0.sql +++ b/priv/migrations/mysql_4.2.0_5.0.0.sql @@ -1,60 +1,35 @@ -- MOD_LAST -ALTER TABLE last ADD server varchar(250); -UPDATE last SET server = 'localhost'; -ALTER TABLE last MODIFY COLUMN server varchar(250) NOT NULL; +ALTER TABLE last ADD server varchar(250) NOT NULL DEFAULT ''; +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; -START TRANSACTION; -ALTER TABLE last DROP PRIMARY KEY; -ALTER TABLE last ADD PRIMARY KEY(server, username); -COMMIT; - -- MOD_PRIVACY -- Table privacy_default_list -ALTER TABLE privacy_default_list ADD COLUMN server varchar(250); -UPDATE privacy_default_list SET server = 'localhost'; -ALTER TABLE privacy_default_list MODIFY COLUMN server varchar(250) NOT NULL; - -START TRANSACTION; -ALTER TABLE privacy_default_list DROP PRIMARY KEY; -ALTER TABLE privacy_default_list ADD PRIMARY KEY (server, username); -COMMIT; +ALTER TABLE privacy_default_list ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; +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; -UPDATE privacy_list SET server = 'localhost'; -ALTER TABLE privacy_list MODIFY COLUMN server varchar(250) NOT NULL; - -START TRANSACTION; -ALTER TABLE privacy_list DROP PRIMARY KEY; -ALTER TABLE privacy_list ADD PRIMARY KEY (server, username, name); -COMMIT; +ALTER TABLE privacy_list ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE privacy_list DROP PRIMARY KEY, ADD PRIMARY KEY (server, username, name); -- MOD_PRIVATE -ALTER TABLE private_storage ADD server varchar(250); -UPDATE private_storage SET server = 'localhost'; -ALTER TABLE private_storage MODIFY COLUMN server varchar(250) NOT NULL; +ALTER TABLE private_storage ADD server varchar(250) NOT NULL DEFAULT ''; +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; -ALTER TABLE private_storage ADD PRIMARY KEY (server, username, namespace); - -- 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 DROP COLUMN `type`, DROP COLUMN subscribe, DROP COLUMN server; -ALTER TABLE rosterusers ADD server varchar(250); -UPDATE rosterusers SET server = 'localhost'; -ALTER TABLE rosterusers MODIFY COLUMN server varchar(250) NOT NULL; +ALTER TABLE rosterusers ADD server varchar(250) NOT NULL DEFAULT ''; CREATE UNIQUE INDEX i_rosteru_server_user_jid ON rosterusers (server, username, jid); CREATE INDEX i_rosteru_server_user ON rosterusers (server, username); @@ -62,48 +37,30 @@ DROP INDEX i_rosteru_user_jid ON rosterusers; DROP INDEX i_rosteru_username ON rosterusers; -- Table rostergroups -ALTER TABLE rostergroups ADD server varchar(250); -UPDATE rostergroups SET server = 'localhost'; -ALTER TABLE rostergroups MODIFY COLUMN server varchar(250) NOT NULL; +ALTER TABLE rostergroups ADD server varchar(250) NOT NULL DEFAULT ''; 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); -UPDATE roster_version SET server = 'localhost'; -ALTER TABLE roster_version MODIFY COLUMN server varchar(250) NOT NULL; +ALTER TABLE roster_version ADD server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE roster_version DROP PRIMARY KEY, ADD PRIMARY KEY (server, username); -START TRANSACTION; -ALTER TABLE roster_version DROP PRIMARY KEY; -ALTER TABLE roster_version ADD PRIMARY KEY (server, username); -COMMIT; - --- MOD_MUC +-- 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 -START TRANSACTION; -ALTER TABLE inbox DROP PRIMARY KEY; -ALTER TABLE inbox ADD PRIMARY KEY (lserver, luser, remote_bare_jid); -COMMIT; +ALTER TABLE inbox DROP PRIMARY KEY, ADD PRIMARY KEY (lserver, luser, remote_bare_jid); -CREATE INDEX i_inbox_timestamp ON inbox(lserver, luser, timestamp); 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); -UPDATE users SET server = 'localhost'; -ALTER TABLE users MODIFY COLUMN server varchar(250) NOT NULL; - -START TRANSACTION; -ALTER TABLE users DROP PRIMARY KEY; -ALTER TABLE users ADD PRIMARY KEY (server, username); -COMMIT; +ALTER TABLE users ADD server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE users DROP PRIMARY KEY, ADD PRIMARY KEY (server, username); -- Table domain_settings -- Mapping from domain hostname to host_type. diff --git a/priv/migrations/pgsql_4.2.0_5.0.0.sql b/priv/migrations/pgsql_4.2.0_5.0.0.sql index 2dd0ce2f6f2..a71e251ac24 100644 --- a/priv/migrations/pgsql_4.2.0_5.0.0.sql +++ b/priv/migrations/pgsql_4.2.0_5.0.0.sql @@ -1,123 +1,67 @@ -- MOD_LAST -ALTER TABLE last ADD COLUMN server varchar(250); -UPDATE last SET server = 'localhost'; -ALTER TABLE last ALTER COLUMN server SET NOT NULL; +ALTER TABLE last ADD COLUMN server varchar(250) NOT NULL DEFAULT''; +ALTER TABLE last DROP CONSTRAINT last_pkey, ADD PRIMARY KEY (server, username); -CREATE UNIQUE INDEX i_last_su ON last (server, username); CREATE INDEX i_last_server_seconds ON last (server, seconds); DROP INDEX i_last_seconds; -BEGIN; -ALTER TABLE last DROP CONSTRAINT last_pkey; -ALTER TABLE last ADD CONSTRAINT last_pkey PRIMARY KEY USING INDEX i_last_su; -COMMIT; - -- MOD_PRIVACY -- Table privacy_default_list -ALTER TABLE privacy_default_list ADD COLUMN server varchar(250); -UPDATE privacy_default_list SET server = 'localhost'; -ALTER TABLE privacy_default_list ALTER COLUMN server SET NOT NULL; - -CREATE UNIQUE INDEX i_privacy_default_list_su ON privacy_default_list (server, username); - -BEGIN; -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; -COMMIT; +ALTER TABLE privacy_default_list ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; +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); -UPDATE privacy_list SET server = 'localhost'; -ALTER TABLE privacy_list ALTER COLUMN server SET NOT NULL; - -CREATE UNIQUE INDEX i_privacy_list_sun ON privacy_list (server, username, name); - -BEGIN; -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; +ALTER TABLE privacy_list ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE privacy_list DROP CONSTRAINT privacy_list_pkey, ADD PRIMARY KEY (server, username, name); -- MOD_PRIVATE -ALTER TABLE private_storage ADD server varchar(250); -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 (server, username, namespace); +-- Table private_storage +ALTER TABLE private_storage ADD server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE private_storage ADD PRIMARY KEY (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; - -- MOD_ROASTER --Table rosterusers -ALTER TABLE rosterusers DROP COLUMN "type"; -ALTER TABLE rosterusers DROP COLUMN subscribe; -ALTER TABLE rosterusers DROP COLUMN server; - -ALTER TABLE rosterusers ADD COLUMN server varchar(250); -UPDATE rosterusers SET server = 'localhost'; -ALTER TABLE rosterusers ALTER COLUMN server SET NOT NULL; +ALTER TABLE rosterusers DROP COLUMN "type", DROP COLUMN subscribe, DROP COLUMN server; +ALTER TABLE rosterusers ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; 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); -UPDATE rostergroups SET server = 'localhost'; -ALTER TABLE rostergroups ALTER COLUMN server SET NOT NULL; - +ALTER TABLE rostergroups ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; 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); -UPDATE roster_version SET server = 'localhost'; -ALTER TABLE roster_version ALTER COLUMN server SET NOT NULL; - -CREATE UNIQUE INDEX i_roster_version_su ON roster_version (server, username); - -BEGIN; -ALTER TABLE roster_version DROP CONSTRAINT roster_version_pkey; -ALTER TABLE roster_version ADD CONSTRAINT roster_version_pkey PRIMARY KEY USING INDEX i_roster_version_su; -COMMIT; +ALTER TABLE roster_version ADD server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE roster_version DROP CONSTRAINT roster_version_pkey, ADD PRIMARY KEY (server, username); --- MOD_MUC +-- MOD_MUC_LIGHT -CREATE INDEX i_muc_light_blocking_su ON muc_light_blocking(lserver, luser); +CREATE INDEX i_muc_light_blocking_su ON muc_light_blocking (lserver, luser); DROP INDEX i_muc_light_blocking; -- MOD_INBOX -CREATE UNIQUE INDEX i_inbox_sur ON inbox (lserver, luser, remote_bare_jid); - -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); +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); -UPDATE users SET server = 'localhost'; -ALTER TABLE users ALTER COLUMN server SET NOT NULL; - -CREATE UNIQUE INDEX i_users_su ON users (server, username); - -BEGIN; -ALTER TABLE users DROP CONSTRAINT users_pkey; -ALTER TABLE users ADD CONSTRAINT users_pkey PRIMARY KEY USING INDEX i_users_su; -COMMIT; +ALTER TABLE users ADD COLUMN server varchar(250) NOT NULL DEFAULT ''; +ALTER TABLE users DROP CONSTRAINT users_pkey, ADD PRIMARY KEY (server, username); -- Table domain_settings -- Mapping from domain hostname to host_type. diff --git a/priv/mssql2012.sql b/priv/mssql2012.sql index b02a522ca93..df8bf99e0d3 100644 --- a/priv/mssql2012.sql +++ b/priv/mssql2012.sql @@ -214,7 +214,9 @@ CREATE TABLE [dbo].[privacy_list]( [created_at] [datetime] NOT NULL, CONSTRAINT [PK_privacy_list] PRIMARY KEY CLUSTERED ( - [server], [username] + [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]