From ec6f5c17c8fd86b94089735945ca0625a2c6567a Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Mon, 12 Dec 2022 16:04:18 +0000 Subject: [PATCH 01/12] Correct README for creating test docker MS SQL DB --- test/docker/README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/test/docker/README.md b/test/docker/README.md index b19321215..93b1a3504 100644 --- a/test/docker/README.md +++ b/test/docker/README.md @@ -21,7 +21,7 @@ The following commands will create the necessary login, user and database, will ``` docker exec ejabberd-mssql /opt/mssql-tools/bin/sqlcmd -U SA -P ejabberd_Test1 -S localhost -i /initdb_mssql.sql -docker exec ejabberd-mssql /opt/mssql-tools/bin/sqlcmd -U SA -P ejabberd_Test1 -S localhost -i /mssql.sql +docker exec ejabberd-mssql /opt/mssql-tools/bin/sqlcmd -U SA -P ejabberd_Test1 -S localhost -d ejabberd_test -i /mssql.sql ``` ## Running tests From 5e94fdcfd54fc44e2332c9cf265901635cf529e3 Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Fri, 9 Dec 2022 09:50:52 +0000 Subject: [PATCH 02/12] MS SQL schema fixes * Add missing 'mix' tables and indexes * Fix text vs varchar issues Various tests triggered this error: The data types text and varchar are incompatible in the equal to operator. Caused by incompatible 'text' columns in muc_online_room, muc_online_users, pubsub_node_option, and pubsub_node tables. * Fix definition of mqtt_pub table This table incorrectly included 'server_host' column in old schema, and had other inconsistencies. --- sql/mssql.sql | 126 +++++++++++++++++++++++++++++++++++++------------- 1 file changed, 94 insertions(+), 32 deletions(-) diff --git a/sql/mssql.sql b/sql/mssql.sql index 928f19fab..355b5316b 100644 --- a/sql/mssql.sql +++ b/sql/mssql.sql @@ -118,10 +118,10 @@ CREATE INDEX [muc_room_host_created_at] ON [muc_registered] (host, nick) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); CREATE TABLE [dbo].[muc_online_room] ( - [name] [varchar] (250) NOT NULL, - [host] [varchar] (250) NOT NULL, - [node] [text] NOT NULL, - [pid] [text] NOT NULL + [name] [varchar] (250) NOT NULL, + [host] [varchar] (250) NOT NULL, + [node] [varchar] (250) NOT NULL, + [pid] [varchar] (100) NOT NULL ); CREATE UNIQUE CLUSTERED INDEX [muc_online_room_name_host] ON [muc_online_room] (name, host) @@ -133,7 +133,7 @@ CREATE TABLE [dbo].[muc_online_users] ( [resource] [varchar] (250) NOT NULL, [name] [varchar] (250) NOT NULL, [host] [varchar] (250) NOT NULL, - node text NOT NULL + [node] [varchar] (250) NOT NULL ); CREATE UNIQUE INDEX [muc_online_users_i] ON [muc_online_users] (username, server, resource, name, host) @@ -226,9 +226,9 @@ WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW CREATE TABLE [dbo].[pubsub_node_option] ( [nodeid] [bigint] NULL, - [name] [text] NOT NULL, - [val] [text] NOT NULL -) TEXTIMAGE_ON [PRIMARY]; + [name] [varchar] (250) NOT NULL, + [val] [varchar] (250) NOT NULL +); CREATE CLUSTERED INDEX [pubsub_node_option_nodeid] ON [pubsub_node_option] (nodeid) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); @@ -272,13 +272,13 @@ CREATE TABLE [dbo].[pubsub_node] ( [host] [varchar] (255) NOT NULL, [node] [varchar] (255) NOT NULL, [parent] [varchar] (255) NOT NULL DEFAULT '', - [plugin] [text] NOT NULL, + [plugin] [varchar] (32) NOT NULL, [nodeid] [bigint] IDENTITY(1,1) NOT NULL, CONSTRAINT [pubsub_node_PRIMARY] PRIMARY KEY CLUSTERED ( [nodeid] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) -) TEXTIMAGE_ON [PRIMARY]; +); CREATE INDEX [pubsub_node_parent] ON [pubsub_node] (parent) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); @@ -366,13 +366,12 @@ WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW CREATE TABLE [dbo].[sr_group] ( [name] [varchar] (250) NOT NULL, [opts] [text] NOT NULL, - [created_at] [datetime] NOT NULL DEFAULT GETDATE(), - CONSTRAINT [sr_group_PRIMARY] PRIMARY KEY CLUSTERED -( - [name] ASC -)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) + [created_at] [datetime] NOT NULL DEFAULT GETDATE() ) TEXTIMAGE_ON [PRIMARY]; +CREATE UNIQUE CLUSTERED INDEX [sr_group_name] ON [sr_group] ([name]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + CREATE TABLE [dbo].[sr_user] ( [jid] [varchar] (250) NOT NULL, [grp] [varchar] (250) NOT NULL, @@ -548,22 +547,85 @@ WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW CREATE UNIQUE INDEX [i_push_ut] ON [push_session] (username, timestamp) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); +CREATE TABLE [dbo].[mix_channel] ( + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [username] [varchar] (250) NOT NULL, + [domain] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL, + [hidden] [smallint] NOT NULL, + [hmac_key] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [mix_channel] ON [mix_channel] (channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_channel_serv] ON [mix_channel] (service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_participant] ( + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [username] [varchar] (250) NOT NULL, + [domain] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL, + [id] [text] NOT NULL, + [nick] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE INDEX [mix_participant] ON [mix_participant] (channel, service, username, domain) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_participant_chan_serv] ON [mix_participant] (channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_subscription] ( + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [username] [varchar] (250) NOT NULL, + [domain] [varchar] (250) NOT NULL, + [node] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL +); + +CREATE UNIQUE INDEX [mix_subscription] ON [mix_subscription] (channel, service, username, domain, node) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_subscription_chan_serv_ud] ON [mix_subscription] (channel, service, username, domain) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_subscription_chan_serv_node] ON [mix_subscription] (channel, service, node) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_subscription_chan_serv] ON [mix_subscription] (channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_pam] ( + [username] [varchar] (250) NOT NULL, + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [id] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [mix_pam] ON [mix_pam] (username, channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + CREATE TABLE [dbo].[mqtt_pub] ( - [username] [varchar](191) NOT NULL, - [server_host] [varchar](191) NOT NULL, - [resource] [varchar](191) NOT NULL, - [topic] [varchar](191) NOT NULL, - [qos] [tinyint] NOT NULL, - [payload] [varbinary](max) NOT NULL, - [payload_format] [tinyint] NOT NULL, - [content_type] [text] NOT NULL, - [response_topic] [text] NOT NULL, - [correlation_data] [varbinary](max) NOT NULL, - [user_properties] [varbinary](max) NOT NULL, - [expiry] [int] NOT NULL, - CONSTRAINT [i_mqtt_topic_server] PRIMARY KEY CLUSTERED -( - [topic] ASC, - [server_host] ASC -)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY] + [username] [varchar] (250) NOT NULL, + [resource] [varchar] (250) NOT NULL, + [topic] [varchar] (250) NOT NULL, + [qos] [tinyint] NOT NULL, + [payload] [varbinary](max) NOT NULL, + [payload_format] [tinyint] NOT NULL, + [content_type] [text] NOT NULL, + [response_topic] [text] NOT NULL, + [correlation_data] [varbinary](max) NOT NULL, + [user_properties] [varbinary](max) NOT NULL, + [expiry] [int] NOT NULL ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [mqtt_topic] ON [mqtt_pub] (topic) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); From 19f2f1fa862320afa1e86a153eb312aaaced663e Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Mon, 12 Dec 2022 16:05:46 +0000 Subject: [PATCH 03/12] Fix MS SQL error caused by ORDER BY in subquery 'The ORDER BY clause is invalid in views, inline functions, derived tables, subqueries, and common table expressions, unless TOP, OFFSET or FOR XML is also specified.' Omit the ORDER BY clause from subquery if the SELECT is not constrained by TOP. --- src/mod_mam_sql.erl | 7 ++++++- 1 file changed, 6 insertions(+), 1 deletion(-) diff --git a/src/mod_mam_sql.erl b/src/mod_mam_sql.erl index 2d60aea4b..695542387 100644 --- a/src/mod_mam_sql.erl +++ b/src/mod_mam_sql.erl @@ -441,6 +441,11 @@ make_sql_query(User, LServer, MAMQuery, RSM, ExtraUsernames) -> true -> [] end, + SubOrderClause = if LimitClause /= [], TopClause /= [] -> + <<" ORDER BY timestamp DESC ">>; + true -> + [] + end, WithTextClause = if is_binary(WithText), WithText /= <<>> -> [<<" and match (txt) against (">>, ToString(WithText), <<")">>]; @@ -528,7 +533,7 @@ make_sql_query(User, LServer, MAMQuery, RSM, ExtraUsernames) -> % XEP-0059: Result Set Management % 2.5 Requesting the Last Page in a Result Set [<<"SELECT">>, UserSel, <<" timestamp, xml, peer, kind, nick FROM (">>, - Query, <<" ORDER BY timestamp DESC ">>, + Query, SubOrderClause, LimitClause, <<") AS t ORDER BY timestamp ASC;">>]; _ -> [Query, <<" ORDER BY timestamp ASC ">>, From 93bf4d5411137cc48a51464487236938f039b113 Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 17 Nov 2022 12:03:09 +0000 Subject: [PATCH 04/12] New SQL schema migrate fix 'server_host' column on 'route' table already exists in old schema and does not need adding for new schema migration. --- sql/pg.new.sql | 5 ----- src/mod_admin_update_sql.erl | 5 ----- 2 files changed, 10 deletions(-) diff --git a/sql/pg.new.sql b/sql/pg.new.sql index de1c28a2e..4a742756d 100644 --- a/sql/pg.new.sql +++ b/sql/pg.new.sql @@ -170,11 +170,6 @@ -- CREATE INDEX i_mix_pam_us ON mix_pam (username, server_host); -- ALTER TABLE mix_pam ALTER COLUMN server_host DROP DEFAULT; --- ALTER TABLE route ADD COLUMN server_host text NOT NULL DEFAULT ''; --- DROP INDEX i_route; --- CREATE UNIQUE INDEX i_route ON route USING btree (domain, server_host, node, pid); --- ALTER TABLE i_route ALTER COLUMN server_host DROP DEFAULT; - -- ALTER TABLE mqtt_pub ADD COLUMN server_host text NOT NULL DEFAULT ''; -- DROP INDEX i_mqtt_topic; -- CREATE UNIQUE INDEX i_mqtt_topic_server ON mqtt_pub (topic, server_host); diff --git a/src/mod_admin_update_sql.erl b/src/mod_admin_update_sql.erl index adcc5b117..3a6aa0dfb 100644 --- a/src/mod_admin_update_sql.erl +++ b/src/mod_admin_update_sql.erl @@ -271,11 +271,6 @@ update_tables(State) -> create_index(State, "mix_pam", "i_mix_pam_us", ["username", "server_host"]), drop_sh_default(State, "mix_pam"), - add_sh_column(State, "route"), - drop_index(State, "i_route"), - create_unique_index(State, "route", "i_route", ["domain", "server_host", "node", "pid"]), - drop_sh_default(State, "route"), - add_sh_column(State, "mqtt_pub"), drop_index(State, "i_mqtt_topic"), create_unique_index(State, "mqtt_pub", "i_mqtt_topic_server", ["topic", "server_host"]), From 06ffe995e1db6168c15200028360517c54212ed4 Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Tue, 22 Nov 2022 12:15:35 +0000 Subject: [PATCH 05/12] Remove unnecessary indexes For columns are already included in a compound index there is no benefit to having a separate index with a subset of the same columns in the same order, it just wastes space. --- sql/lite.new.sql | 12 ------------ sql/lite.sql | 10 ---------- sql/mssql.sql | 17 ----------------- sql/mysql.new.sql | 14 ++------------ sql/mysql.old-to-new.sql | 5 ----- sql/mysql.sql | 10 ---------- sql/pg.new.sql | 31 ++++--------------------------- sql/pg.sql | 10 ---------- src/mod_admin_update_sql.erl | 5 ----- 9 files changed, 6 insertions(+), 108 deletions(-) diff --git a/sql/lite.new.sql b/sql/lite.new.sql index d9ba4dee8..43baa0e1b 100644 --- a/sql/lite.new.sql +++ b/sql/lite.new.sql @@ -52,7 +52,6 @@ CREATE TABLE rosterusers ( ); CREATE UNIQUE INDEX i_rosteru_sh_user_jid ON rosterusers (server_host, username, jid); -CREATE INDEX i_rosteru_sh_username ON rosterusers (server_host, username); CREATE INDEX i_rosteru_sh_jid ON rosterusers (server_host, jid); @@ -84,7 +83,6 @@ CREATE TABLE sr_user ( ); CREATE UNIQUE INDEX i_sr_user_sh_jid_grp ON sr_user (server_host, jid, grp); -CREATE INDEX i_sr_user_sh_jid ON sr_user (server_host, jid); CREATE INDEX i_sr_user_sh_grp ON sr_user (server_host, grp); CREATE TABLE spool ( @@ -190,7 +188,6 @@ CREATE TABLE privacy_list ( created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); -CREATE INDEX i_privacy_list_sh_username ON privacy_list (server_host, username); CREATE UNIQUE INDEX i_privacy_list_sh_username_name ON privacy_list (server_host, username, name); CREATE TABLE privacy_list_data ( @@ -215,9 +212,6 @@ CREATE TABLE private_storage ( PRIMARY KEY (server_host, username, namespace) ); -CREATE INDEX i_private_storage_sh_username ON private_storage (server_host, username); - - CREATE TABLE roster_version ( username text NOT NULL, server_host text NOT NULL, @@ -319,7 +313,6 @@ CREATE TABLE muc_online_users ( ); CREATE UNIQUE INDEX i_muc_online_users ON muc_online_users (username, server, resource, name, host); -CREATE INDEX i_muc_online_users_us ON muc_online_users (username, server); CREATE TABLE muc_room_subscribers ( room text NOT NULL, @@ -389,7 +382,6 @@ CREATE TABLE route ( ); CREATE UNIQUE INDEX i_route ON route(domain, server_host, node, pid); -CREATE INDEX i_route_domain ON route(domain); CREATE TABLE bosh ( sid text NOT NULL, @@ -449,7 +441,6 @@ CREATE TABLE mix_participant ( ); 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, @@ -461,9 +452,7 @@ CREATE TABLE mix_subscription ( ); 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, @@ -475,7 +464,6 @@ CREATE TABLE mix_pam ( ); 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); CREATE TABLE mqtt_pub ( username text NOT NULL, diff --git a/sql/lite.sql b/sql/lite.sql index fbba55c9d..a920a6cd5 100644 --- a/sql/lite.sql +++ b/sql/lite.sql @@ -47,7 +47,6 @@ CREATE TABLE rosterusers ( ); CREATE UNIQUE INDEX i_rosteru_user_jid ON rosterusers (username, jid); -CREATE INDEX i_rosteru_username ON rosterusers (username); CREATE INDEX i_rosteru_jid ON rosterusers (jid); @@ -74,7 +73,6 @@ CREATE TABLE sr_user ( ); CREATE UNIQUE INDEX i_sr_user_jid_grp ON sr_user (jid, grp); -CREATE INDEX i_sr_user_jid ON sr_user (jid); CREATE INDEX i_sr_user_grp ON sr_user (grp); CREATE TABLE spool ( @@ -169,7 +167,6 @@ CREATE TABLE privacy_list ( created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); -CREATE INDEX i_privacy_list_username ON privacy_list (username); CREATE UNIQUE INDEX i_privacy_list_username_name ON privacy_list (username, name); CREATE TABLE privacy_list_data ( @@ -192,7 +189,6 @@ CREATE TABLE private_storage ( created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); -CREATE INDEX i_private_storage_username ON private_storage (username); CREATE UNIQUE INDEX i_private_storage_username_namespace ON private_storage (username, namespace); @@ -291,7 +287,6 @@ CREATE TABLE muc_online_users ( ); CREATE UNIQUE INDEX i_muc_online_users ON muc_online_users (username, server, resource, name, host); -CREATE INDEX i_muc_online_users_us ON muc_online_users (username, server); CREATE TABLE muc_room_subscribers ( room text NOT NULL, @@ -358,7 +353,6 @@ CREATE TABLE route ( ); CREATE UNIQUE INDEX i_route ON route(domain, server_host, node, pid); -CREATE INDEX i_route_domain ON route(domain); CREATE TABLE bosh ( sid text NOT NULL, @@ -417,7 +411,6 @@ CREATE TABLE mix_participant ( ); 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, @@ -429,9 +422,7 @@ CREATE TABLE mix_subscription ( ); 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, @@ -442,7 +433,6 @@ CREATE TABLE mix_pam ( ); CREATE UNIQUE INDEX i_mix_pam ON mix_pam (username, channel, service); -CREATE INDEX i_mix_pam_us ON mix_pam (username); CREATE TABLE mqtt_pub ( username text NOT NULL, diff --git a/sql/mssql.sql b/sql/mssql.sql index 355b5316b..66c523e53 100644 --- a/sql/mssql.sql +++ b/sql/mssql.sql @@ -138,8 +138,6 @@ CREATE TABLE [dbo].[muc_online_users] ( CREATE UNIQUE INDEX [muc_online_users_i] ON [muc_online_users] (username, server, resource, name, host) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); -CREATE UNIQUE CLUSTERED INDEX [muc_online_users_us] ON [muc_online_users] (username, server) -WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); CREATE TABLE [dbo].[muc_room_subscribers] ( [room] [varchar] (191) NOT NULL, @@ -174,9 +172,6 @@ CREATE TABLE [dbo].[privacy_list] ( )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ); -CREATE INDEX [privacy_list_username] ON [privacy_list] (username) -WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); - CREATE UNIQUE INDEX [privacy_list_username_name] ON [privacy_list] (username, name) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); @@ -203,9 +198,6 @@ CREATE TABLE [dbo].[private_storage] ( [created_at] [datetime] NOT NULL DEFAULT GETDATE() ) TEXTIMAGE_ON [PRIMARY]; -CREATE INDEX [private_storage_username] ON [private_storage] (username) -WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); - CREATE UNIQUE CLUSTERED INDEX [private_storage_username_namespace] ON [private_storage] (username, namespace) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); @@ -320,9 +312,6 @@ CREATE TABLE [dbo].[rosterusers] ( CREATE UNIQUE CLUSTERED INDEX [rosterusers_username_jid] ON [rosterusers] ([username], [jid]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); -CREATE INDEX [rosterusers_username] ON [rosterusers] ([username]) -WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); - CREATE INDEX [rosterusers_jid] ON [rosterusers] ([jid]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); @@ -381,9 +370,6 @@ CREATE TABLE [dbo].[sr_user] ( CREATE UNIQUE CLUSTERED INDEX [sr_user_jid_group] ON [sr_user] ([jid], [grp]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); -CREATE INDEX [sr_user_jid] ON [sr_user] ([jid]) -WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); - CREATE INDEX [sr_user_grp] ON [sr_user] ([grp]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); @@ -520,9 +506,6 @@ CREATE TABLE [dbo].[route] ( CREATE UNIQUE CLUSTERED INDEX [route_i] ON [route] (domain, server_host, node, pid) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); -CREATE INDEX [route_domain] ON [route] (domain) -WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); - CREATE TABLE [dbo].[bosh] ( [sid] [varchar] (255) NOT NULL, [node] [varchar] (255) NOT NULL, diff --git a/sql/mysql.new.sql b/sql/mysql.new.sql index f60016794..cbd9414aa 100644 --- a/sql/mysql.new.sql +++ b/sql/mysql.new.sql @@ -56,7 +56,6 @@ CREATE TABLE rosterusers ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_rosteru_sh_user_jid ON rosterusers(server_host(191), username(75), jid(75)); -CREATE INDEX i_rosteru_sh_username ON rosterusers(server_host(191), username); CREATE INDEX i_rosteru_sh_jid ON rosterusers(server_host(191), jid); CREATE TABLE rostergroups ( @@ -87,7 +86,6 @@ CREATE TABLE sr_user ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_sr_user_sh_jid_group ON sr_user(server_host(191), jid, grp); -CREATE INDEX i_sr_user_sh_jid ON sr_user(server_host(191), jid); CREATE INDEX i_sr_user_sh_grp ON sr_user(server_host(191), grp); CREATE TABLE spool ( @@ -195,7 +193,6 @@ CREATE TABLE privacy_list ( created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -CREATE INDEX i_privacy_list_sh_username USING BTREE ON privacy_list(server_host(191), username); CREATE UNIQUE INDEX i_privacy_list_sh_username_name USING BTREE ON privacy_list (server_host(191), username(75), name(75)); CREATE TABLE privacy_list_data ( @@ -218,11 +215,10 @@ CREATE TABLE private_storage ( server_host varchar(191) NOT NULL, namespace varchar(191) NOT NULL, data text NOT NULL, - created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, - PRIMARY KEY (server_host(191), username, namespace) + created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -CREATE INDEX i_private_storage_sh_username USING BTREE ON private_storage(server_host(191), username); +CREATE UNIQUE INDEX i_private_storage_sh_sername_namespace USING BTREE ON private_storage(server_host(191), username, namespace); -- Not tested in mysql CREATE TABLE roster_version ( @@ -335,7 +331,6 @@ CREATE TABLE muc_online_users ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_muc_online_users USING BTREE ON muc_online_users(username(75), server(75), resource(75), name(75), host(75)); -CREATE INDEX i_muc_online_users_us USING BTREE ON muc_online_users(username(75), server(75)); CREATE TABLE muc_room_subscribers ( room varchar(191) NOT NULL, @@ -405,7 +400,6 @@ CREATE TABLE route ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_route ON route(domain(75), server_host(75), node(75), pid(75)); -CREATE INDEX i_route_domain ON route(domain(75)); CREATE TABLE bosh ( sid text NOT NULL, @@ -465,7 +459,6 @@ CREATE TABLE mix_participant ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_mix_participant ON mix_participant (channel(191), service(191), username(191), domain(191)); -CREATE INDEX i_mix_participant_chan_serv ON mix_participant (channel(191), service(191)); CREATE TABLE mix_subscription ( channel text NOT NULL, @@ -477,9 +470,7 @@ CREATE TABLE mix_subscription ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_mix_subscription ON mix_subscription (channel(153), service(153), username(153), domain(153), node(153)); -CREATE INDEX i_mix_subscription_chan_serv_ud ON mix_subscription (channel(191), service(191), username(191), domain(191)); CREATE INDEX i_mix_subscription_chan_serv_node ON mix_subscription (channel(191), service(191), node(191)); -CREATE INDEX i_mix_subscription_chan_serv ON mix_subscription (channel(191), service(191)); CREATE TABLE mix_pam ( username text NOT NULL, @@ -491,7 +482,6 @@ CREATE TABLE mix_pam ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_mix_pam ON mix_pam (username(191), server_host(191), channel(191), service(191)); -CREATE INDEX i_mix_pam_us ON mix_pam (username(191), server_host(191)); CREATE TABLE mqtt_pub ( username varchar(191) NOT NULL, diff --git a/sql/mysql.old-to-new.sql b/sql/mysql.old-to-new.sql index 9614d55a8..ae3ab490f 100644 --- a/sql/mysql.old-to-new.sql +++ b/sql/mysql.old-to-new.sql @@ -33,14 +33,12 @@ BEGIN ALTER TABLE `rosterusers` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `rosterusers` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `rosterusers` ADD UNIQUE INDEX `i_rosteru_sh_user_jid` (`server_host`, `username`(75), `jid`(75)); - ALTER TABLE `rosterusers` ADD INDEX `i_rosteru_sh_username` (`server_host`, `username`); ALTER TABLE `rosterusers` ADD INDEX `i_rosteru_sh_jid` (`server_host`, `jid`); ALTER TABLE `private_storage` DROP INDEX `i_private_storage_username_namespace`; ALTER TABLE `private_storage` DROP INDEX `i_private_storage_username`; ALTER TABLE `private_storage` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `private_storage` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `private_storage` ADD PRIMARY KEY (`server_host`, `username`, `namespace`); - ALTER TABLE `private_storage` ADD INDEX `i_private_storage_sh_username` USING BTREE (`server_host`, `username`); ALTER TABLE `mqtt_pub` DROP INDEX `i_mqtt_topic`; ALTER TABLE `mqtt_pub` ADD COLUMN `server_host` VARCHAR (191) NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `mqtt_pub` ALTER COLUMN `server_host` DROP DEFAULT; @@ -94,14 +92,12 @@ BEGIN ALTER TABLE `privacy_list` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `privacy_list` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `privacy_list` ADD UNIQUE INDEX `i_privacy_list_sh_username_name` USING BTREE (`server_host`, `username`(75), `name`(75)); - ALTER TABLE `privacy_list` ADD INDEX `i_privacy_list_sh_username` USING BTREE (`server_host`, `username`); ALTER TABLE `sr_user` DROP INDEX `i_sr_user_jid`; ALTER TABLE `sr_user` DROP INDEX `i_sr_user_grp`; ALTER TABLE `sr_user` DROP INDEX `i_sr_user_jid_group`; ALTER TABLE `sr_user` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `jid`; ALTER TABLE `sr_user` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `sr_user` ADD UNIQUE INDEX `i_sr_user_sh_jid_group` (`server_host`, `jid`, `grp`); - ALTER TABLE `sr_user` ADD INDEX `i_sr_user_sh_jid` (`server_host`, `jid`); ALTER TABLE `sr_user` ADD INDEX `i_sr_user_sh_grp` (`server_host`, `grp`); ALTER TABLE `sr_user` ADD PRIMARY KEY (`server_host`, `jid`, `grp`); ALTER TABLE `muc_online_users` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `host`; @@ -119,7 +115,6 @@ BEGIN ALTER TABLE `mix_pam` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `mix_pam` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `mix_pam` ADD UNIQUE INDEX `i_mix_pam` (`username`(191), `server_host`, `channel`(191), `service`(191)); - ALTER TABLE `mix_pam` ADD INDEX `i_mix_pam_us` (`username`(191), `server_host`); ALTER TABLE `route` CHANGE COLUMN `server_host` `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL; ALTER TABLE `users` DROP PRIMARY KEY; ALTER TABLE `users` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; diff --git a/sql/mysql.sql b/sql/mysql.sql index d6fcb000c..af93302dd 100644 --- a/sql/mysql.sql +++ b/sql/mysql.sql @@ -51,7 +51,6 @@ CREATE TABLE rosterusers ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_rosteru_user_jid ON rosterusers(username(75), jid(75)); -CREATE INDEX i_rosteru_username ON rosterusers(username); CREATE INDEX i_rosteru_jid ON rosterusers(jid); CREATE TABLE rostergroups ( @@ -77,7 +76,6 @@ CREATE TABLE sr_user ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_sr_user_jid_group ON sr_user(jid(75), grp(75)); -CREATE INDEX i_sr_user_jid ON sr_user(jid); CREATE INDEX i_sr_user_grp ON sr_user(grp); CREATE TABLE spool ( @@ -174,7 +172,6 @@ CREATE TABLE privacy_list ( created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -CREATE INDEX i_privacy_list_username USING BTREE ON privacy_list(username); CREATE UNIQUE INDEX i_privacy_list_username_name USING BTREE ON privacy_list (username(75), name(75)); CREATE TABLE privacy_list_data ( @@ -199,7 +196,6 @@ CREATE TABLE private_storage ( created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -CREATE INDEX i_private_storage_username USING BTREE ON private_storage(username); CREATE UNIQUE INDEX i_private_storage_username_namespace USING BTREE ON private_storage(username(75), namespace(75)); -- Not tested in mysql @@ -307,7 +303,6 @@ CREATE TABLE muc_online_users ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_muc_online_users USING BTREE ON muc_online_users(username(75), server(75), resource(75), name(75), host(75)); -CREATE INDEX i_muc_online_users_us USING BTREE ON muc_online_users(username(75), server(75)); CREATE TABLE muc_room_subscribers ( room varchar(191) NOT NULL, @@ -374,7 +369,6 @@ CREATE TABLE route ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_route ON route(domain(75), server_host(75), node(75), pid(75)); -CREATE INDEX i_route_domain ON route(domain(75)); CREATE TABLE bosh ( sid text NOT NULL, @@ -433,7 +427,6 @@ CREATE TABLE mix_participant ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_mix_participant ON mix_participant (channel(191), service(191), username(191), domain(191)); -CREATE INDEX i_mix_participant_chan_serv ON mix_participant (channel(191), service(191)); CREATE TABLE mix_subscription ( channel text NOT NULL, @@ -445,9 +438,7 @@ CREATE TABLE mix_subscription ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_mix_subscription ON mix_subscription (channel(153), service(153), username(153), domain(153), node(153)); -CREATE INDEX i_mix_subscription_chan_serv_ud ON mix_subscription (channel(191), service(191), username(191), domain(191)); CREATE INDEX i_mix_subscription_chan_serv_node ON mix_subscription (channel(191), service(191), node(191)); -CREATE INDEX i_mix_subscription_chan_serv ON mix_subscription (channel(191), service(191)); CREATE TABLE mix_pam ( username text NOT NULL, @@ -458,7 +449,6 @@ CREATE TABLE mix_pam ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_mix_pam ON mix_pam (username(191), channel(191), service(191)); -CREATE INDEX i_mix_pam_u ON mix_pam (username(191)); CREATE TABLE mqtt_pub ( username varchar(191) NOT NULL, diff --git a/sql/pg.new.sql b/sql/pg.new.sql index 4a742756d..f3888da07 100644 --- a/sql/pg.new.sql +++ b/sql/pg.new.sql @@ -30,10 +30,8 @@ -- ALTER TABLE rosterusers ADD COLUMN server_host text NOT NULL DEFAULT ''; -- DROP INDEX i_rosteru_user_jid; --- DROP INDEX i_rosteru_username; -- DROP INDEX i_rosteru_jid; -- CREATE UNIQUE INDEX i_rosteru_sh_user_jid ON rosterusers USING btree (server_host, username, jid); --- CREATE INDEX i_rosteru_sh_username ON rosterusers USING btree (server_host, username); -- CREATE INDEX i_rosteru_sh_jid ON rosterusers USING btree (server_host, jid); -- ALTER TABLE rosterusers ALTER COLUMN server_host DROP DEFAULT; @@ -48,10 +46,8 @@ -- ALTER TABLE sr_user ADD COLUMN server_host text NOT NULL DEFAULT ''; -- DROP INDEX i_sr_user_jid_grp; --- DROP INDEX i_sr_user_jid; -- DROP INDEX i_sr_user_grp; -- ALTER TABLE sr_user ADD PRIMARY KEY (server_host, jid, grp); --- CREATE INDEX i_sr_user_sh_jid ON sr_user USING btree (server_host, jid); -- CREATE INDEX i_sr_user_sh_grp ON sr_user USING btree (server_host, grp); -- ALTER TABLE sr_user ALTER COLUMN server_host DROP DEFAULT; @@ -114,17 +110,13 @@ -- ALTER TABLE privacy_default_list ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE privacy_list ADD COLUMN server_host text NOT NULL DEFAULT ''; --- DROP INDEX i_privacy_list_username; -- DROP INDEX i_privacy_list_username_name; --- CREATE INDEX i_privacy_list_sh_username ON privacy_list USING btree (server_host, username); -- CREATE UNIQUE INDEX i_privacy_list_sh_username_name ON privacy_list USING btree (server_host, username, name); -- ALTER TABLE privacy_list ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE private_storage ADD COLUMN server_host text NOT NULL DEFAULT ''; --- DROP INDEX i_private_storage_username; -- DROP INDEX i_private_storage_username_namespace; -- ALTER TABLE private_storage ADD PRIMARY KEY (server_host, username, namespace); --- CREATE INDEX i_private_storage_sh_username ON private_storage USING btree (server_host, username); -- ALTER TABLE private_storage ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE roster_version ADD COLUMN server_host text NOT NULL DEFAULT ''; @@ -165,9 +157,7 @@ -- ALTER TABLE mix_pam ADD COLUMN server_host text NOT NULL DEFAULT ''; -- DROP INDEX i_mix_pam; --- DROP INDEX 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 mix_pam ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE mqtt_pub ADD COLUMN server_host text NOT NULL DEFAULT ''; @@ -216,7 +206,6 @@ CREATE TABLE rosterusers ( ); CREATE UNIQUE INDEX i_rosteru_sh_user_jid ON rosterusers USING btree (server_host, username, jid); -CREATE INDEX i_rosteru_sh_username ON rosterusers USING btree (server_host, username); CREATE INDEX i_rosteru_sh_jid ON rosterusers USING btree (server_host, jid); @@ -233,8 +222,7 @@ CREATE TABLE sr_group ( name text NOT NULL, server_host text NOT NULL, opts text NOT NULL, - created_at TIMESTAMP NOT NULL DEFAULT now(), - PRIMARY KEY (server_host, name) + created_at TIMESTAMP NOT NULL DEFAULT now() ); CREATE UNIQUE INDEX i_sr_group_sh_name ON sr_group USING btree (server_host, name); @@ -243,12 +231,10 @@ CREATE TABLE sr_user ( jid text NOT NULL, server_host text NOT NULL, grp text NOT NULL, - created_at TIMESTAMP NOT NULL DEFAULT now(), - PRIMARY KEY (server_host, jid, grp) + created_at TIMESTAMP NOT NULL DEFAULT now() ); CREATE UNIQUE INDEX i_sr_user_sh_jid_grp ON sr_user USING btree (server_host, jid, grp); -CREATE INDEX i_sr_user_sh_jid ON sr_user USING btree (server_host, jid); CREATE INDEX i_sr_user_sh_grp ON sr_user USING btree (server_host, grp); CREATE TABLE spool ( @@ -354,7 +340,6 @@ CREATE TABLE privacy_list ( created_at TIMESTAMP NOT NULL DEFAULT now() ); -CREATE INDEX i_privacy_list_sh_username ON privacy_list USING btree (server_host, username); CREATE UNIQUE INDEX i_privacy_list_sh_username_name ON privacy_list USING btree (server_host, username, name); CREATE TABLE privacy_list_data ( @@ -377,12 +362,10 @@ CREATE TABLE private_storage ( server_host text NOT NULL, namespace text NOT NULL, data text NOT NULL, - created_at TIMESTAMP NOT NULL DEFAULT now(), - PRIMARY KEY (server_host, username, namespace) + created_at TIMESTAMP NOT NULL DEFAULT now() ); -CREATE INDEX i_private_storage_sh_username ON private_storage USING btree (server_host, username); - +CREATE UNIQUE INDEX i_private_storage_sh_username_namespace ON private_storage USING btree (server_host, username, namespace); CREATE TABLE roster_version ( username text NOT NULL, @@ -497,7 +480,6 @@ CREATE TABLE muc_online_users ( ); CREATE UNIQUE INDEX i_muc_online_users ON muc_online_users USING btree (username, server, resource, name, host); -CREATE INDEX i_muc_online_users_us ON muc_online_users USING btree (username, server); CREATE TABLE muc_room_subscribers ( room text NOT NULL, @@ -569,7 +551,6 @@ CREATE TABLE route ( ); CREATE UNIQUE INDEX i_route ON route USING btree (domain, server_host, node, pid); -CREATE INDEX i_route_domain ON route USING btree (domain); CREATE TABLE bosh ( sid text NOT NULL, @@ -629,7 +610,6 @@ CREATE TABLE mix_participant ( ); 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, @@ -641,9 +621,7 @@ CREATE TABLE mix_subscription ( ); 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, @@ -655,7 +633,6 @@ CREATE TABLE mix_pam ( ); 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); CREATE TABLE mqtt_pub ( username text NOT NULL, diff --git a/sql/pg.sql b/sql/pg.sql index 03e3d5294..5a0d4b766 100644 --- a/sql/pg.sql +++ b/sql/pg.sql @@ -51,7 +51,6 @@ CREATE TABLE rosterusers ( ); CREATE UNIQUE INDEX i_rosteru_user_jid ON rosterusers USING btree (username, jid); -CREATE INDEX i_rosteru_username ON rosterusers USING btree (username); CREATE INDEX i_rosteru_jid ON rosterusers USING btree (jid); @@ -78,7 +77,6 @@ CREATE TABLE sr_user ( ); CREATE UNIQUE INDEX i_sr_user_jid_grp ON sr_user USING btree (jid, grp); -CREATE INDEX i_sr_user_jid ON sr_user USING btree (jid); CREATE INDEX i_sr_user_grp ON sr_user USING btree (grp); CREATE TABLE spool ( @@ -173,7 +171,6 @@ CREATE TABLE privacy_list ( created_at TIMESTAMP NOT NULL DEFAULT now() ); -CREATE INDEX i_privacy_list_username ON privacy_list USING btree (username); CREATE UNIQUE INDEX i_privacy_list_username_name ON privacy_list USING btree (username, name); CREATE TABLE privacy_list_data ( @@ -198,7 +195,6 @@ CREATE TABLE private_storage ( created_at TIMESTAMP NOT NULL DEFAULT now() ); -CREATE INDEX i_private_storage_username ON private_storage USING btree (username); CREATE UNIQUE INDEX i_private_storage_username_namespace ON private_storage USING btree (username, namespace); @@ -309,7 +305,6 @@ CREATE TABLE muc_online_users ( ); CREATE UNIQUE INDEX i_muc_online_users ON muc_online_users USING btree (username, server, resource, name, host); -CREATE INDEX i_muc_online_users_us ON muc_online_users USING btree (username, server); CREATE TABLE muc_room_subscribers ( room text NOT NULL, @@ -378,7 +373,6 @@ CREATE TABLE route ( ); CREATE UNIQUE INDEX i_route ON route USING btree (domain, server_host, node, pid); -CREATE INDEX i_route_domain ON route USING btree (domain); CREATE TABLE bosh ( sid text NOT NULL, @@ -437,7 +431,6 @@ CREATE TABLE mix_participant ( ); 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, @@ -449,9 +442,7 @@ CREATE TABLE mix_subscription ( ); 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, @@ -462,7 +453,6 @@ CREATE TABLE mix_pam ( ); CREATE UNIQUE INDEX i_mix_pam ON mix_pam (username, channel, service); -CREATE INDEX i_mix_pam_us ON mix_pam (username); CREATE TABLE mqtt_pub ( username text NOT NULL, diff --git a/src/mod_admin_update_sql.erl b/src/mod_admin_update_sql.erl index 3a6aa0dfb..e9f248f5c 100644 --- a/src/mod_admin_update_sql.erl +++ b/src/mod_admin_update_sql.erl @@ -129,7 +129,6 @@ update_tables(State) -> drop_index(State, "i_rosteru_username"), drop_index(State, "i_rosteru_jid"), create_unique_index(State, "rosterusers", "i_rosteru_sh_user_jid", ["server_host", "username", "jid"]), - create_index(State, "rosterusers", "i_rosteru_sh_username", ["server_host", "username"]), create_index(State, "rosterusers", "i_rosteru_sh_jid", ["server_host", "jid"]), drop_sh_default(State, "rosterusers"), @@ -149,7 +148,6 @@ update_tables(State) -> drop_index(State, "i_sr_user_grp"), add_pkey(State, "sr_user", ["server_host", "jid", "grp"]), create_unique_index(State, "sr_user", "i_sr_user_sh_jid_grp", ["server_host", "jid", "grp"]), - create_index(State, "sr_user", "i_sr_user_sh_jid", ["server_host", "jid"]), create_index(State, "sr_user", "i_sr_user_sh_grp", ["server_host", "grp"]), drop_sh_default(State, "sr_user"), @@ -217,7 +215,6 @@ update_tables(State) -> add_sh_column(State, "privacy_list"), drop_index(State, "i_privacy_list_username"), drop_index(State, "i_privacy_list_username_name"), - create_index(State, "privacy_list", "i_privacy_list_sh_username", ["server_host", "username"]), create_unique_index(State, "privacy_list", "i_privacy_list_sh_username_name", ["server_host", "username", "name"]), drop_sh_default(State, "privacy_list"), @@ -225,7 +222,6 @@ update_tables(State) -> drop_index(State, "i_private_storage_username"), drop_index(State, "i_private_storage_username_namespace"), add_pkey(State, "private_storage", ["server_host", "username", "namespace"]), - create_index(State, "private_storage", "i_private_storage_sh_username", ["server_host", "username"]), drop_sh_default(State, "private_storage"), add_sh_column(State, "roster_version"), @@ -268,7 +264,6 @@ update_tables(State) -> drop_index(State, "i_mix_pam"), drop_index(State, "i_mix_pam_us"), create_unique_index(State, "mix_pam", "i_mix_pam", ["username", "server_host", "channel", "service"]), - create_index(State, "mix_pam", "i_mix_pam_us", ["username", "server_host"]), drop_sh_default(State, "mix_pam"), add_sh_column(State, "mqtt_pub"), From 6fc67d83f4b5e1f2f09527e7e27373be9795cffb Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Sat, 14 Jan 2023 12:03:41 +0000 Subject: [PATCH 06/12] Minor MS SQL improvements Support 'sql_ssl' option for MS SQL - set Encryption=required and Encrypt=yes in ODBC connection string to require SSL using default FreeTDS driver and Microsoft ODBC Driver for SQL Server repectively. Allow setting full ODBC connection string in 'sql_server' for MS SQL, allowing custom connection configuration beyond what is possible with just 'sql_odbc_driver' option. --- src/ejabberd_options_doc.erl | 18 +++++++++++------- src/ejabberd_sql.erl | 33 +++++++++++++++++++++++++++++---- 2 files changed, 40 insertions(+), 11 deletions(-) diff --git a/src/ejabberd_options_doc.erl b/src/ejabberd_options_doc.erl index fb04d9c86..ba4b585b3 100644 --- a/src/ejabberd_options_doc.erl +++ b/src/ejabberd_options_doc.erl @@ -1293,9 +1293,9 @@ doc() -> note => "added in 20.12", desc => ?T("Path to the ODBC driver to use to connect to a Microsoft SQL " - "Server database. This option is only valid if the _`sql_type`_ " - "option is set to 'mssql'. " - "The default value is: 'libtdsodbc.so'")}}, + "Server database. This option only applies if the _`sql_type`_ " + "option is set to 'mssql' and _`sql_server`_ is not an ODBC " + "connection string. The default value is: 'libtdsodbc.so'")}}, {sql_password, #{value => ?T("Password"), desc => @@ -1334,14 +1334,15 @@ doc() -> {sql_server, #{value => ?T("Host"), desc => - ?T("A hostname or an IP address of the SQL server. " + ?T("The hostname or IP address of the SQL server. For _`sql_type`_ " + "'mssql' or 'odbc' this can also be an ODBC connection string. " "The default value is 'localhost'.")}}, {sql_ssl, #{value => "true | false", note => "improved in 20.03", desc => ?T("Whether to use SSL encrypted connections to the " - "SQL server. The option is only available for MySQL and " + "SQL server. The option is only available for MySQL, MS SQL and " "PostgreSQL. The default value is 'false'.")}}, {sql_ssl_cafile, #{value => ?T("Path"), @@ -1350,7 +1351,8 @@ doc() -> "be used to verify SQL connections. Implies _`sql_ssl`_ " "and _`sql_ssl_verify`_ options are set to 'true'. " "There is no default which means " - "certificate verification is disabled.")}}, + "certificate verification is disabled. " + "This option has no effect for MS SQL.")}}, {sql_ssl_certfile, #{value => ?T("Path"), desc => @@ -1358,13 +1360,15 @@ doc() -> "for SSL connections to the SQL server. Implies _`sql_ssl`_ " "option is set to 'true'. There is no default which means " "ejabberd won't provide a client certificate to the SQL " - "server.")}}, + "server. " + "This option has no effect for MS SQL.")}}, {sql_ssl_verify, #{value => "true | false", desc => ?T("Whether to verify SSL connection to the SQL server against " "CA root certificates defined in _`sql_ssl_cafile`_ option. " "Implies _`sql_ssl`_ option is set to 'true'. " + "This option has no effect for MS SQL. " "The default value is 'false'.")}}, {sql_start_interval, #{value => "timeout()", diff --git a/src/ejabberd_sql.erl b/src/ejabberd_sql.erl index ebe106464..4e92e0574 100644 --- a/src/ejabberd_sql.erl +++ b/src/ejabberd_sql.erl @@ -1159,9 +1159,19 @@ db_opts(Host) -> SSLOpts = get_ssl_opts(Transport, Host), case Type of mssql -> - [mssql, <<"DRIVER=ODBC;SERVER=", Server/binary, ";UID=", User/binary, - ";DATABASE=", DB/binary ,";PWD=", Pass/binary, - ";PORT=", (integer_to_binary(Port))/binary ,";CLIENT_CHARSET=UTF-8;">>, Timeout]; + case odbc_server_is_connstring(Server) of + true -> + [mssql, Server, Timeout]; + false -> + Encryption = case Transport of + tcp -> <<"">>; + ssl -> <<";ENCRYPTION=require;ENCRYPT=yes">> + end, + [mssql, <<"DRIVER=ODBC;SERVER=", Server/binary, ";DATABASE=", DB/binary, + ";UID=", User/binary, ";PWD=", Pass/binary, + ";PORT=", (integer_to_binary(Port))/binary, Encryption/binary, + ";CLIENT_CHARSET=UTF-8;">>, Timeout] + end; _ -> [Type, Server, Port, DB, User, Pass, Timeout, Transport, SSLOpts] end @@ -1171,6 +1181,8 @@ warn_if_ssl_unsupported(tcp, _) -> ok; warn_if_ssl_unsupported(ssl, pgsql) -> ok; +warn_if_ssl_unsupported(ssl, mssql) -> + ok; warn_if_ssl_unsupported(ssl, mysql) -> ok; warn_if_ssl_unsupported(ssl, Type) -> @@ -1203,7 +1215,7 @@ get_ssl_opts(ssl, Host) -> get_ssl_opts(tcp, _) -> []. -init_mssql(Host) -> +init_mssql_odbcinst(Host) -> Driver = ejabberd_option:sql_odbc_driver(Host), ODBCINST = io_lib:fwrite("[ODBC]~n" "Driver = ~s~n", [Driver]), @@ -1225,6 +1237,19 @@ init_mssql(Host) -> Err end. +init_mssql(Host) -> + Server = ejabberd_option:sql_server(Host), + case odbc_server_is_connstring(Server) of + true -> ok; + false -> init_mssql_odbcinst(Host) + end. + +odbc_server_is_connstring(Server) -> + case binary:match(Server, <<"=">>) of + nomatch -> false; + _ -> true + end. + write_file_if_new(File, Payload) -> case filelib:is_file(File) of true -> ok; From aeed1679d8b3193ff5508d09754a8c2ac6f2cbe0 Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 19 Jan 2023 13:05:30 +0000 Subject: [PATCH 07/12] Add 'new' schema for MS SQL --- sql/mssql.new.sql | 646 +++++++++++++++++++++++++++++++++ test/docker/docker-compose.yml | 1 + 2 files changed, 647 insertions(+) create mode 100644 sql/mssql.new.sql diff --git a/sql/mssql.new.sql b/sql/mssql.new.sql new file mode 100644 index 000000000..f72b40bfa --- /dev/null +++ b/sql/mssql.new.sql @@ -0,0 +1,646 @@ +-- +-- ejabberd, Copyright (C) 2002-2023 ProcessOne +-- +-- This program is free software; you can redistribute it and/or +-- modify it under the terms of the GNU General Public License as +-- published by the Free Software Foundation; either version 2 of the +-- License, or (at your option) any later version. +-- +-- This program is distributed in the hope that it will be useful, +-- but WITHOUT ANY WARRANTY; without even the implied warranty of +-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU +-- General Public License for more details. +-- +-- You should have received a copy of the GNU General Public License along +-- with this program; if not, write to the Free Software Foundation, Inc., +-- 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. +-- + +SET ANSI_PADDING OFF; +SET ANSI_NULLS ON; +SET QUOTED_IDENTIFIER ON; +SET ANSI_PADDING ON; + +CREATE TABLE [dbo].[archive] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [timestamp] [bigint] NOT NULL, + [peer] [varchar] (250) NOT NULL, + [bare_peer] [varchar] (250) NOT NULL, + [xml] [ntext] NOT NULL, + [txt] [ntext] NULL, + [id] [bigint] IDENTITY(1,1) NOT NULL, + [kind] [varchar] (10) NULL, + [nick] [varchar] (250) NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [archive_PK] PRIMARY KEY CLUSTERED +( + [id] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE INDEX [archive_sh_username_timestamp] ON [archive] (server_host, username, timestamp) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [archive_sh_username_peer] ON [archive] (server_host, username, peer) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [archive_sh_username_bare_peer] ON [archive] (server_host, username, bare_peer) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [archive_sh_timestamp] ON [archive] (server_host, timestamp) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[archive_prefs] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [def] [text] NOT NULL, + [always] [text] NOT NULL, + [never] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [archive_prefs_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[caps_features] ( + [node] [varchar] (250) NOT NULL, + [subnode] [varchar] (250) NOT NULL, + [feature] [text] NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE CLUSTERED INDEX [caps_features_node_subnode] ON [caps_features] (node, subnode) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[last] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [seconds] [text] NOT NULL, + [state] [text] NOT NULL, + CONSTRAINT [last_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[motd] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [xml] [text] NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [motd_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[muc_registered] ( + [jid] [varchar] (255) NOT NULL, + [host] [varchar] (255) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [nick] [varchar] (255) NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +); + +CREATE INDEX [muc_registered_nick] ON [muc_registered] (nick) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE UNIQUE CLUSTERED INDEX [muc_registered_jid_host] ON [muc_registered] (jid, host) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[muc_room] ( + [name] [varchar] (250) NOT NULL, + [host] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [opts] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [muc_room_name_host] ON [muc_room] (name, host) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); +CREATE INDEX [muc_room_host_created_at] ON [muc_registered] (host, nick) + WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[muc_online_room] ( + [name] [varchar] (250) NOT NULL, + [host] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [node] [varchar] (250) NOT NULL, + [pid] [varchar] (100) NOT NULL +); + +CREATE UNIQUE CLUSTERED INDEX [muc_online_room_name_host] ON [muc_online_room] (name, host) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[muc_online_users] ( + [username] [varchar] (250) NOT NULL, + [server] [varchar] (250) NOT NULL, + [resource] [varchar] (250) NOT NULL, + [name] [varchar] (250) NOT NULL, + [host] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [node] [varchar] (250) NOT NULL +); + +CREATE UNIQUE INDEX [muc_online_users_i] ON [muc_online_users] (username, server, resource, name, host) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[muc_room_subscribers] ( + [room] [varchar] (191) NOT NULL, + [host] [varchar] (191) NOT NULL, + [jid] [varchar] (191) NOT NULL, + [nick] [text] NOT NULL, + [nodes] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +); + +CREATE UNIQUE CLUSTERED INDEX [muc_room_subscribers_host_room_jid] ON [muc_room_subscribers] (host, room, jid); +CREATE INDEX [muc_room_subscribers_host_jid] ON [muc_room_subscribers] (host, jid); +CREATE INDEX [muc_room_subscribers_jid] ON [muc_room_subscribers] (jid); + +CREATE TABLE [dbo].[privacy_default_list] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [name] [varchar] (250) NOT NULL, + CONSTRAINT [privacy_default_list_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +); + +CREATE TABLE [dbo].[privacy_list] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [name] [varchar] (250) NOT NULL, + [id] [bigint] IDENTITY(1,1) NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [privacy_list_PK] PRIMARY KEY CLUSTERED +( + [id] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +); + +CREATE UNIQUE INDEX [privacy_list_sh_username_name] ON [privacy_list] (server_host, username, name) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[privacy_list_data] ( + [id] [bigint] NULL, + [t] [char] (1) NOT NULL, + [value] [text] NOT NULL, + [action] [char] (1) NOT NULL, + [ord] [smallint] NOT NULL, + [match_all] [smallint] NOT NULL, + [match_iq] [smallint] NOT NULL, + [match_message] [smallint] NOT NULL, + [match_presence_in] [smallint] NOT NULL, + [match_presence_out] [smallint] NOT NULL +) TEXTIMAGE_ON [PRIMARY]; + +CREATE CLUSTERED INDEX [privacy_list_data_id] ON [privacy_list_data] (id) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[private_storage] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [namespace] [varchar] (250) NOT NULL, + [data] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [private_storage_sh_username_namespace] ON [private_storage] (server_host, username, namespace) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[pubsub_item] ( + [nodeid] [bigint] NULL, + [itemid] [varchar] (255) NOT NULL, + [publisher] [varchar] (250) NOT NULL, + [creation] [varchar] (32) NOT NULL, + [modification] [varchar] (32) NOT NULL, + [payload] [text] NOT NULL DEFAULT '' +) TEXTIMAGE_ON [PRIMARY]; + +CREATE INDEX [pubsub_item_itemid] ON [pubsub_item] (itemid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE UNIQUE CLUSTERED INDEX [pubsub_item_nodeid_itemid] ON [pubsub_item] (nodeid, itemid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[pubsub_node_option] ( + [nodeid] [bigint] NULL, + [name] [varchar] (250) NOT NULL, + [val] [varchar] (250) NOT NULL +); + +CREATE CLUSTERED INDEX [pubsub_node_option_nodeid] ON [pubsub_node_option] (nodeid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[pubsub_node_owner] ( + [nodeid] [bigint] NULL, + [owner] [text] NOT NULL +) TEXTIMAGE_ON [PRIMARY]; + +CREATE CLUSTERED INDEX [pubsub_node_owner_nodeid] ON [pubsub_node_owner] (nodeid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[pubsub_state] ( + [nodeid] [bigint] NULL, + [jid] [varchar] (255) NOT NULL, + [affiliation] [char] (1) NOT NULL, + [subscriptions] [text] NOT NULL DEFAULT '', + [stateid] [bigint] IDENTITY(1,1) NOT NULL, + CONSTRAINT [pubsub_state_PRIMARY] PRIMARY KEY CLUSTERED +( + [stateid] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE INDEX [pubsub_state_jid] ON [pubsub_state] (jid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE UNIQUE INDEX [pubsub_state_nodeid_jid] ON [pubsub_state] (nodeid, jid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[pubsub_subscription_opt] ( + [subid] [varchar] (255) NOT NULL, + [opt_name] [varchar] (32) NOT NULL, + [opt_value] [text] NOT NULL +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [pubsub_subscription_opt_subid_opt_name] ON [pubsub_subscription_opt] (subid, opt_name) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[pubsub_node] ( + [host] [varchar] (255) NOT NULL, + [node] [varchar] (255) NOT NULL, + [parent] [varchar] (255) NOT NULL DEFAULT '', + [plugin] [varchar] (32) NOT NULL, + [nodeid] [bigint] IDENTITY(1,1) NOT NULL, + CONSTRAINT [pubsub_node_PRIMARY] PRIMARY KEY CLUSTERED +( + [nodeid] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +); + +CREATE INDEX [pubsub_node_parent] ON [pubsub_node] (parent) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE UNIQUE INDEX [pubsub_node_host_node] ON [pubsub_node] (host, node) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[roster_version] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [version] [text] NOT NULL, + CONSTRAINT [roster_version_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[rostergroups] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL, + [grp] [text] NOT NULL +) TEXTIMAGE_ON [PRIMARY]; + +CREATE CLUSTERED INDEX [rostergroups_sh_username_jid] ON [rostergroups] ([server_host], [username], [jid]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[rosterusers] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL, + [nick] [text] NOT NULL, + [subscription] [char] (1) NOT NULL, + [ask] [char] (1) NOT NULL, + [askmessage] [text] NOT NULL, + [server] [char] (1) NOT NULL, + [subscribe] [text] NOT NULL, + [type] [text] NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [rosterusers_sh_username_jid] ON [rosterusers] ([server_host], [username], [jid]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [rosterusers_sh_jid] ON [rosterusers] ([server_host], [jid]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[sm] ( + [usec] [bigint] NOT NULL, + [pid] [varchar] (100) NOT NULL, + [node] [varchar] (255) NOT NULL, + [username] [varchar] (255) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [resource] [varchar] (255) NOT NULL, + [priority] [text] NOT NULL, + [info] [text] NOT NULL +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [sm_sid] ON [sm] (usec, pid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [sm_node] ON [sm] (node) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [sm_sh_username] ON [sm] (server_host, username) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[spool] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [xml] [text] NOT NULL, + [seq] [bigint] IDENTITY(1,1) NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [spool_PK] PRIMARY KEY CLUSTERED +( + [seq] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE INDEX [spool_sh_username] ON [spool] (server_host, username) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [spool_created_at] ON [spool] (created_at) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +; + +CREATE TABLE [dbo].[sr_group] ( + [name] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [opts] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [sr_group_sh_name] ON [sr_group] ([server_host], [name]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[sr_user] ( + [jid] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [grp] [varchar] (250) NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +); + +CREATE UNIQUE CLUSTERED INDEX [sr_user_sh_jid_group] ON [sr_user] ([server_host], [jid], [grp]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [sr_user_sh_grp] ON [sr_user] ([server_host], [grp]) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[users] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [password] [text] NOT NULL, + [serverkey] [text] NOT NULL DEFAULT '', + [salt] [text] NOT NULL DEFAULT '', + [iterationcount] [smallint] NOT NULL DEFAULT 0, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [users_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[vcard] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [vcard] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE(), + CONSTRAINT [vcard_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [username] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[vcard_search] ( + [username] [varchar] (250) NOT NULL, + [lusername] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [fn] [text] NOT NULL, + [lfn] [varchar] (250) NOT NULL, + [family] [text] NOT NULL, + [lfamily] [varchar] (250) NOT NULL, + [given] [text] NOT NULL, + [lgiven] [varchar] (250) NOT NULL, + [middle] [text] NOT NULL, + [lmiddle] [varchar] (250) NOT NULL, + [nickname] [text] NOT NULL, + [lnickname] [varchar] (250) NOT NULL, + [bday] [text] NOT NULL, + [lbday] [varchar] (250) NOT NULL, + [ctry] [text] NOT NULL, + [lctry] [varchar] (250) NOT NULL, + [locality] [text] NOT NULL, + [llocality] [varchar] (250) NOT NULL, + [email] [text] NOT NULL, + [lemail] [varchar] (250) NOT NULL, + [orgname] [text] NOT NULL, + [lorgname] [varchar] (250) NOT NULL, + [orgunit] [text] NOT NULL, + [lorgunit] [varchar] (250) NOT NULL, + CONSTRAINT [vcard_search_PRIMARY] PRIMARY KEY CLUSTERED +( + [server_host] ASC, + [lusername] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE INDEX [vcard_search_sh_lfn] ON [vcard_search] (server_host, lfn) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lfamily] ON [vcard_search] (server_host, lfamily) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lgiven] ON [vcard_search] (server_host, lgiven) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lmiddle] ON [vcard_search] (server_host, lmiddle) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lnickname] ON [vcard_search] (server_host, lnickname) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lbday] ON [vcard_search] (server_host, lbday) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lctry] ON [vcard_search] (server_host, lctry) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_llocality] ON [vcard_search] (server_host, llocality) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lemail] ON [vcard_search] (server_host, lemail) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lorgname] ON [vcard_search] (server_host, lorgname) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [vcard_search_sh_lorgunit] ON [vcard_search] (server_host, lorgunit) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +ALTER TABLE [dbo].[pubsub_item] WITH CHECK ADD CONSTRAINT [pubsub_item_ibfk_1] FOREIGN KEY([nodeid]) +REFERENCES [dbo].[pubsub_node] ([nodeid]) +ON DELETE CASCADE; + +ALTER TABLE [dbo].[pubsub_item] CHECK CONSTRAINT [pubsub_item_ibfk_1]; + +ALTER TABLE [dbo].[pubsub_node_option] WITH CHECK ADD CONSTRAINT [pubsub_node_option_ibfk_1] FOREIGN KEY([nodeid]) +REFERENCES [dbo].[pubsub_node] ([nodeid]) +ON DELETE CASCADE; + +ALTER TABLE [dbo].[pubsub_node_option] CHECK CONSTRAINT [pubsub_node_option_ibfk_1]; + +ALTER TABLE [dbo].[pubsub_node_owner] WITH CHECK ADD CONSTRAINT [pubsub_node_owner_ibfk_1] FOREIGN KEY([nodeid]) +REFERENCES [dbo].[pubsub_node] ([nodeid]) +ON DELETE CASCADE; + +ALTER TABLE [dbo].[pubsub_node_owner] CHECK CONSTRAINT [pubsub_node_owner_ibfk_1]; + +ALTER TABLE [dbo].[pubsub_state] WITH CHECK ADD CONSTRAINT [pubsub_state_ibfk_1] FOREIGN KEY([nodeid]) +REFERENCES [dbo].[pubsub_node] ([nodeid]) +ON DELETE CASCADE; + +ALTER TABLE [dbo].[pubsub_state] CHECK CONSTRAINT [pubsub_state_ibfk_1]; + +CREATE TABLE [dbo].[oauth_token] ( + [token] [varchar] (250) NOT NULL, + [jid] [text] NOT NULL, + [scope] [text] NOT NULL, + [expire] [bigint] NOT NULL, + CONSTRAINT [oauth_token_PRIMARY] PRIMARY KEY CLUSTERED +( + [token] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +) TEXTIMAGE_ON [PRIMARY]; + +CREATE TABLE [dbo].[route] ( + [domain] [varchar] (255) NOT NULL, + [server_host] [varchar] (255) NOT NULL, + [node] [varchar] (255) NOT NULL, + [pid] [varchar](100) NOT NULL, + [local_hint] [text] NOT NULL +); + +CREATE UNIQUE CLUSTERED INDEX [route_i] ON [route] (domain, server_host, node, pid) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[bosh] ( + [sid] [varchar] (255) NOT NULL, + [node] [varchar] (255) NOT NULL, + [pid] [varchar](100) NOT NULL + CONSTRAINT [bosh_PRIMARY] PRIMARY KEY CLUSTERED +( + [sid] ASC +)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) +); + +CREATE TABLE [dbo].[push_session] ( + [username] [varchar] (255) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [timestamp] [bigint] NOT NULL, + [service] [varchar] (255) NOT NULL, + [node] [varchar] (255) NOT NULL, + [xml] [varchar] (255) NOT NULL +); + +CREATE UNIQUE NONCLUSTERED INDEX [push_session_susn] ON [push_session] (server_host, username, service, node)) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [push_session_sh_username_timestamp] ON [push_session] (server_host, username, timestamp) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_channel] ( + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [username] [varchar] (250) NOT NULL, + [domain] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL, + [hidden] [smallint] NOT NULL, + [hmac_key] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [mix_channel] ON [mix_channel] (channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_channel_serv] ON [mix_channel] (service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_participant] ( + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [username] [varchar] (250) NOT NULL, + [domain] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL, + [id] [text] NOT NULL, + [nick] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE INDEX [mix_participant] ON [mix_participant] (channel, service, username, domain) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_participant_chan_serv] ON [mix_participant] (channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_subscription] ( + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [username] [varchar] (250) NOT NULL, + [domain] [varchar] (250) NOT NULL, + [node] [varchar] (250) NOT NULL, + [jid] [varchar] (250) NOT NULL +); + +CREATE UNIQUE INDEX [mix_subscription] ON [mix_subscription] (channel, service, username, domain, node) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_subscription_chan_serv_ud] ON [mix_subscription] (channel, service, username, domain) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_subscription_chan_serv_node] ON [mix_subscription] (channel, service, node) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE INDEX [mix_subscription_chan_serv] ON [mix_subscription] (channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mix_pam] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [channel] [varchar] (250) NOT NULL, + [service] [varchar] (250) NOT NULL, + [id] [text] NOT NULL, + [created_at] [datetime] NOT NULL DEFAULT GETDATE() +) TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE NONCLUSTERED INDEX [mix_pam] ON [mix_pam] (username, server_host, channel, service) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); + +CREATE TABLE [dbo].[mqtt_pub] ( + [username] [varchar] (250) NOT NULL, + [server_host] [varchar] (250) NOT NULL, + [resource] [varchar] (250) NOT NULL, + [topic] [varchar] (250) NOT NULL, + [qos] [tinyint] NOT NULL, + [payload] [varbinary](max) NOT NULL, + [payload_format] [tinyint] NOT NULL, + [content_type] [text] NOT NULL, + [response_topic] [text] NOT NULL, + [correlation_data] [varbinary](max) NOT NULL, + [user_properties] [varbinary](max) NOT NULL, + [expiry] [int] NOT NULL +) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; + +CREATE UNIQUE CLUSTERED INDEX [mqtt_topic_server] ON [mqtt_pub] (topic, server_host) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); diff --git a/test/docker/docker-compose.yml b/test/docker/docker-compose.yml index 7ce610eab..bf99ae04e 100644 --- a/test/docker/docker-compose.yml +++ b/test/docker/docker-compose.yml @@ -24,6 +24,7 @@ services: - mssqldata:/var/opt/mssql - ./db/mssql/initdb/initdb_mssql.sql:/initdb_mssql.sql:ro - ../../sql/mssql.sql:/mssql.sql:ro + - ../../sql/mssql.new.sql:/mssql.new.sql:ro restart: always ports: - 1433:1433 From d4ab4d16e88148a97ba926b80a0a901308d2c7ed Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 19 Jan 2023 12:57:33 +0000 Subject: [PATCH 08/12] Use python3 to run extauth.py for tests --- test/ejabberd_SUITE_data/ejabberd.cfg | 2 +- test/ejabberd_SUITE_data/ejabberd.extauth.yml | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/test/ejabberd_SUITE_data/ejabberd.cfg b/test/ejabberd_SUITE_data/ejabberd.cfg index f071ffe8b..251f23118 100644 --- a/test/ejabberd_SUITE_data/ejabberd.cfg +++ b/test/ejabberd_SUITE_data/ejabberd.cfg @@ -64,7 +64,7 @@ {host_config, "localhost", [{auth_method, internal}]}. {host_config, "extauth.localhost", [{auth_method, external}, - {extauth_program, "python extauth.py"}]}. + {extauth_program, "python3 extauth.py"}]}. {host_config, "mnesia.localhost", [{auth_method, internal}, {{add, modules}, [{mod_announce, [{db_type, internal}]}, diff --git a/test/ejabberd_SUITE_data/ejabberd.extauth.yml b/test/ejabberd_SUITE_data/ejabberd.extauth.yml index 660ddccd6..11a67d2cc 100644 --- a/test/ejabberd_SUITE_data/ejabberd.extauth.yml +++ b/test/ejabberd_SUITE_data/ejabberd.extauth.yml @@ -1,5 +1,5 @@ define_macro: EXTAUTH_CONFIG: queue_type: ram - extauth_program: "python extauth.py" + extauth_program: "python3 extauth.py" auth_method: external From f7f0d3b1fba30eedf7033bb1339f4a97acb6248d Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 19 Jan 2023 15:44:44 +0000 Subject: [PATCH 09/12] Enable MySQL support for new schema migration --- sql/mysql.new.sql | 2 +- src/mod_admin_update_sql.erl | 112 +++++++++++++++++++++-------------- 2 files changed, 67 insertions(+), 47 deletions(-) diff --git a/sql/mysql.new.sql b/sql/mysql.new.sql index cbd9414aa..959fbff84 100644 --- a/sql/mysql.new.sql +++ b/sql/mysql.new.sql @@ -85,7 +85,7 @@ CREATE TABLE sr_user ( PRIMARY KEY (server_host(191), jid, grp) ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -CREATE UNIQUE INDEX i_sr_user_sh_jid_group ON sr_user(server_host(191), jid, grp); +CREATE UNIQUE INDEX i_sr_user_sh_jid_grp ON sr_user(server_host(191), jid, grp); CREATE INDEX i_sr_user_sh_grp ON sr_user(server_host(191), grp); CREATE TABLE spool ( diff --git a/src/mod_admin_update_sql.erl b/src/mod_admin_update_sql.erl index e9f248f5c..ec86cece7 100644 --- a/src/mod_admin_update_sql.erl +++ b/src/mod_admin_update_sql.erl @@ -63,7 +63,7 @@ depends(_Host, _Opts) -> get_commands_spec() -> [#ejabberd_commands{name = update_sql, tags = [sql], - desc = "Convert PostgreSQL DB to the new format", + desc = "Convert MySQL or PostgreSQL DB to the new format", module = ?MODULE, function = update_sql, args = [], args_example = [], @@ -93,6 +93,7 @@ update_sql(Host) -> DBType = ejabberd_option:sql_type(LHost), IsSupported = case DBType of + mysql -> true; pgsql -> true; _ -> false end, @@ -125,15 +126,15 @@ update_tables(State) -> drop_sh_default(State, "last"), add_sh_column(State, "rosterusers"), - drop_index(State, "i_rosteru_user_jid"), - drop_index(State, "i_rosteru_username"), - drop_index(State, "i_rosteru_jid"), + drop_index(State, "rosterusers", "i_rosteru_user_jid"), + drop_index(State, "rosterusers", "i_rosteru_username"), + drop_index(State, "rosterusers", "i_rosteru_jid"), create_unique_index(State, "rosterusers", "i_rosteru_sh_user_jid", ["server_host", "username", "jid"]), create_index(State, "rosterusers", "i_rosteru_sh_jid", ["server_host", "jid"]), drop_sh_default(State, "rosterusers"), add_sh_column(State, "rostergroups"), - drop_index(State, "pk_rosterg_user_jid"), + drop_index(State, "rostergroups", "pk_rosterg_user_jid"), create_index(State, "rostergroups", "i_rosterg_sh_user_jid", ["server_host", "username", "jid"]), drop_sh_default(State, "rostergroups"), @@ -143,27 +144,27 @@ update_tables(State) -> drop_sh_default(State, "sr_group"), add_sh_column(State, "sr_user"), - drop_index(State, "i_sr_user_jid_grp"), - drop_index(State, "i_sr_user_jid"), - drop_index(State, "i_sr_user_grp"), + drop_index(State, "sr_user", "i_sr_user_jid_grp"), + drop_index(State, "sr_user", "i_sr_user_jid"), + drop_index(State, "sr_user", "i_sr_user_grp"), add_pkey(State, "sr_user", ["server_host", "jid", "grp"]), create_unique_index(State, "sr_user", "i_sr_user_sh_jid_grp", ["server_host", "jid", "grp"]), create_index(State, "sr_user", "i_sr_user_sh_grp", ["server_host", "grp"]), drop_sh_default(State, "sr_user"), add_sh_column(State, "spool"), - drop_index(State, "i_despool"), + drop_index(State, "spool", "i_despool"), create_index(State, "spool", "i_spool_sh_username", ["server_host", "username"]), drop_sh_default(State, "spool"), add_sh_column(State, "archive"), - drop_index(State, "i_username"), - drop_index(State, "i_username_timestamp"), - drop_index(State, "i_timestamp"), - drop_index(State, "i_peer"), - drop_index(State, "i_bare_peer"), - drop_index(State, "i_username_peer"), - drop_index(State, "i_username_bare_peer"), + drop_index(State, "archive", "i_username"), + drop_index(State, "archive", "i_username_timestamp"), + drop_index(State, "archive", "i_timestamp"), + drop_index(State, "archive", "i_peer"), + drop_index(State, "archive", "i_bare_peer"), + drop_index(State, "archive", "i_username_peer"), + drop_index(State, "archive", "i_username_bare_peer"), create_index(State, "archive", "i_archive_sh_username_timestamp", ["server_host", "username", "timestamp"]), create_index(State, "archive", "i_archive_sh_timestamp", ["server_host", "timestamp"]), create_index(State, "archive", "i_archive_sh_username_peer", ["server_host", "username", "peer"]), @@ -182,17 +183,17 @@ update_tables(State) -> add_sh_column(State, "vcard_search"), drop_pkey(State, "vcard_search"), - drop_index(State, "i_vcard_search_lfn"), - drop_index(State, "i_vcard_search_lfamily"), - drop_index(State, "i_vcard_search_lgiven"), - drop_index(State, "i_vcard_search_lmiddle"), - drop_index(State, "i_vcard_search_lnickname"), - drop_index(State, "i_vcard_search_lbday"), - drop_index(State, "i_vcard_search_lctry"), - drop_index(State, "i_vcard_search_llocality"), - drop_index(State, "i_vcard_search_lemail"), - drop_index(State, "i_vcard_search_lorgname"), - drop_index(State, "i_vcard_search_lorgunit"), + drop_index(State, "vcard_search", "i_vcard_search_lfn"), + drop_index(State, "vcard_search", "i_vcard_search_lfamily"), + drop_index(State, "vcard_search", "i_vcard_search_lgiven"), + drop_index(State, "vcard_search", "i_vcard_search_lmiddle"), + drop_index(State, "vcard_search", "i_vcard_search_lnickname"), + drop_index(State, "vcard_search", "i_vcard_search_lbday"), + drop_index(State, "vcard_search", "i_vcard_search_lctry"), + drop_index(State, "vcard_search", "i_vcard_search_llocality"), + drop_index(State, "vcard_search", "i_vcard_search_lemail"), + drop_index(State, "vcard_search", "i_vcard_search_lorgname"), + drop_index(State, "vcard_search", "i_vcard_search_lorgunit"), add_pkey(State, "vcard_search", ["server_host", "username"]), create_index(State, "vcard_search", "i_vcard_search_sh_lfn", ["server_host", "lfn"]), create_index(State, "vcard_search", "i_vcard_search_sh_lfamily", ["server_host", "lfamily"]), @@ -213,14 +214,14 @@ update_tables(State) -> drop_sh_default(State, "privacy_default_list"), add_sh_column(State, "privacy_list"), - drop_index(State, "i_privacy_list_username"), - drop_index(State, "i_privacy_list_username_name"), + drop_index(State, "privacy_list", "i_privacy_list_username"), + drop_index(State, "privacy_list", "i_privacy_list_username_name"), create_unique_index(State, "privacy_list", "i_privacy_list_sh_username_name", ["server_host", "username", "name"]), drop_sh_default(State, "privacy_list"), add_sh_column(State, "private_storage"), - drop_index(State, "i_private_storage_username"), - drop_index(State, "i_private_storage_username_namespace"), + drop_index(State, "private_storage", "i_private_storage_username"), + drop_index(State, "private_storage", "i_private_storage_username_namespace"), add_pkey(State, "private_storage", ["server_host", "username", "namespace"]), drop_sh_default(State, "private_storage"), @@ -247,27 +248,28 @@ update_tables(State) -> drop_sh_default(State, "motd"), add_sh_column(State, "sm"), - drop_index(State, "i_sm_sid"), - drop_index(State, "i_sm_username"), + drop_index(State, "sm", "i_sm_sid"), + drop_index(State, "sm", "i_sm_username"), add_pkey(State, "sm", ["usec", "pid"]), create_index(State, "sm", "i_sm_sh_username", ["server_host", "username"]), drop_sh_default(State, "sm"), add_sh_column(State, "push_session"), - drop_index(State, "i_push_usn"), - drop_index(State, "i_push_ut"), + drop_index(State, "push_session", "i_push_usn"), + drop_index(State, "push_session", "i_push_ut"), add_pkey(State, "push_session", ["server_host", "username", "timestamp"]), create_unique_index(State, "push_session", "i_push_session_susn", ["server_host", "username", "service", "node"]), drop_sh_default(State, "push_session"), add_sh_column(State, "mix_pam"), - drop_index(State, "i_mix_pam"), - drop_index(State, "i_mix_pam_us"), + drop_index(State, "mix_pam", "i_mix_pam"), + drop_index(State, "mix_pam", "i_mix_pam_u"), + drop_index(State, "mix_pam", "i_mix_pam_us"), create_unique_index(State, "mix_pam", "i_mix_pam", ["username", "server_host", "channel", "service"]), drop_sh_default(State, "mix_pam"), add_sh_column(State, "mqtt_pub"), - drop_index(State, "i_mqtt_topic"), + drop_index(State, "mqtt_pub", "i_mqtt_topic"), create_unique_index(State, "mqtt_pub", "i_mqtt_topic_server", ["topic", "server_host"]), drop_sh_default(State, "mqtt_pub"), @@ -282,7 +284,7 @@ add_sh_column(#state{dbtype = pgsql} = State, Table) -> add_sh_column(#state{dbtype = mysql} = State, Table) -> sql_query( State#state.host, - ["ALTER TABLE ", Table, " ADD COLUMN server_host text NOT NULL DEFAULT '", + ["ALTER TABLE ", Table, " ADD COLUMN server_host varchar(191) NOT NULL DEFAULT '", (State#state.escape)(State#state.host), "';"]). @@ -301,7 +303,8 @@ add_pkey(#state{dbtype = pgsql} = State, Table, Cols) -> State#state.host, ["ALTER TABLE ", Table, " ADD PRIMARY KEY (", SCols, ");"]); add_pkey(#state{dbtype = mysql} = State, Table, Cols) -> - SCols = string:join(Cols, ", "), + Cols2 = [C ++ mysql_keylen(Table, C) || C <- Cols], + SCols = string:join(Cols2, ", "), sql_query( State#state.host, ["ALTER TABLE ", Table, " ADD PRIMARY KEY (", SCols, ");"]). @@ -315,14 +318,14 @@ drop_sh_default(#state{dbtype = mysql} = State, Table) -> State#state.host, ["ALTER TABLE ", Table, " ALTER COLUMN server_host DROP DEFAULT;"]). -drop_index(#state{dbtype = pgsql} = State, Index) -> +drop_index(#state{dbtype = pgsql} = State, _Table, Index) -> sql_query( State#state.host, ["DROP INDEX ", Index, ";"]); -drop_index(#state{dbtype = mysql} = State, Index) -> +drop_index(#state{dbtype = mysql} = State, Table, Index) -> sql_query( State#state.host, - ["DROP INDEX ", Index, ";"]). + ["ALTER TABLE ", Table, " DROP INDEX ", Index, ";"]). create_unique_index(#state{dbtype = pgsql} = State, Table, Index, Cols) -> SCols = string:join(Cols, ", "), @@ -331,7 +334,7 @@ create_unique_index(#state{dbtype = pgsql} = State, Table, Index, Cols) -> ["CREATE UNIQUE INDEX ", Index, " ON ", Table, " USING btree (", SCols, ");"]); create_unique_index(#state{dbtype = mysql} = State, Table, Index, Cols) -> - Cols2 = [C ++ "(75)" || C <- Cols], + Cols2 = [C ++ mysql_keylen(Index, C) || C <- Cols], SCols = string:join(Cols2, ", "), sql_query( State#state.host, @@ -345,13 +348,30 @@ create_index(#state{dbtype = pgsql} = State, Table, Index, Cols) -> ["CREATE INDEX ", Index, " ON ", Table, " USING btree (", SCols, ");"]); create_index(#state{dbtype = mysql} = State, Table, Index, Cols) -> - Cols2 = [C ++ "(75)" || C <- Cols], + Cols2 = [C ++ mysql_keylen(Index, C) || C <- Cols], SCols = string:join(Cols2, ", "), sql_query( State#state.host, ["CREATE INDEX ", Index, " ON ", Table, "(", SCols, ");"]). +mysql_keylen(_, "bare_peer") -> "(191)"; +mysql_keylen(_, "channel") -> "(191)"; +mysql_keylen(_, "domain") -> "(75)"; +mysql_keylen(_, "jid") -> "(75)"; +mysql_keylen(_, "name") -> "(75)"; +mysql_keylen(_, "node") -> "(75)"; +mysql_keylen(_, "peer") -> "(191)"; +mysql_keylen(_, "pid") -> "(75)"; +mysql_keylen(_, "server_host") -> "(191)"; +mysql_keylen(_, "service") -> "(191)"; +mysql_keylen(_, "topic") -> "(191)"; +mysql_keylen("i_privacy_list_sh_username_name", "username") -> "(75)"; +mysql_keylen("i_rosterg_sh_user_jid", "username") -> "(75)"; +mysql_keylen("i_rosteru_sh_user_jid", "username") -> "(75)"; +mysql_keylen(_, "username") -> "(191)"; +mysql_keylen(_, _) -> "". + sql_query(Host, Query) -> io:format("executing \"~ts\" on ~ts~n", [Query, Host]), case ejabberd_sql:sql_query(Host, Query) of @@ -369,5 +389,5 @@ mod_doc() -> ?T("This module can be used to update existing SQL database " "from the default to the new schema. Check the section " "http://../database/#default-and-new-schemas[Default and New Schemas] for details. " - "Please note that only PostgreSQL is supported. " + "Please note that only MySQL and PostgreSQL are supported. " "When the module is loaded use _`update_sql`_ API.")}. From c7c982b67b9df9aad2808411b4509a4da8cf123e Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 19 Jan 2023 19:26:13 +0000 Subject: [PATCH 10/12] Add MS SQL support for new schema migration --- src/mod_admin_update_sql.erl | 77 +++++++++++++++++++++++++++++++++--- 1 file changed, 72 insertions(+), 5 deletions(-) diff --git a/src/mod_admin_update_sql.erl b/src/mod_admin_update_sql.erl index ec86cece7..f3a458a96 100644 --- a/src/mod_admin_update_sql.erl +++ b/src/mod_admin_update_sql.erl @@ -63,7 +63,7 @@ depends(_Host, _Opts) -> get_commands_spec() -> [#ejabberd_commands{name = update_sql, tags = [sql], - desc = "Convert MySQL or PostgreSQL DB to the new format", + desc = "Convert MS SQL, MySQL or PostgreSQL DB to the new format", module = ?MODULE, function = update_sql, args = [], args_example = [], @@ -93,6 +93,7 @@ update_sql(Host) -> DBType = ejabberd_option:sql_type(LHost), IsSupported = case DBType of + mssql -> true; mysql -> true; pgsql -> true; _ -> false @@ -139,7 +140,7 @@ update_tables(State) -> drop_sh_default(State, "rostergroups"), add_sh_column(State, "sr_group"), - add_pkey(State, "sr_group", ["server_host", "name"]), + drop_index(State, "sr_group", "i_sr_group_name"), create_unique_index(State, "sr_group", "i_sr_group_sh_name", ["server_host", "name"]), drop_sh_default(State, "sr_group"), @@ -147,7 +148,6 @@ update_tables(State) -> drop_index(State, "sr_user", "i_sr_user_jid_grp"), drop_index(State, "sr_user", "i_sr_user_jid"), drop_index(State, "sr_user", "i_sr_user_grp"), - add_pkey(State, "sr_user", ["server_host", "jid", "grp"]), create_unique_index(State, "sr_user", "i_sr_user_sh_jid_grp", ["server_host", "jid", "grp"]), create_index(State, "sr_user", "i_sr_user_sh_grp", ["server_host", "grp"]), drop_sh_default(State, "sr_user"), @@ -257,8 +257,8 @@ update_tables(State) -> add_sh_column(State, "push_session"), drop_index(State, "push_session", "i_push_usn"), drop_index(State, "push_session", "i_push_ut"), - add_pkey(State, "push_session", ["server_host", "username", "timestamp"]), create_unique_index(State, "push_session", "i_push_session_susn", ["server_host", "username", "service", "node"]), + create_index(State, "push_session", "i_push_session_sh_username_timestamp", ["server_host", "username", "timestamp"]), drop_sh_default(State, "push_session"), add_sh_column(State, "mix_pam"), @@ -281,6 +281,12 @@ add_sh_column(#state{dbtype = pgsql} = State, Table) -> ["ALTER TABLE ", Table, " ADD COLUMN server_host text NOT NULL DEFAULT '", (State#state.escape)(State#state.host), "';"]); +add_sh_column(#state{dbtype = mssql} = State, Table) -> + sql_query( + State#state.host, + ["ALTER TABLE [", Table, "] ADD [server_host] varchar (250) NOT NULL CONSTRAINT [server_host_default] DEFAULT '", + (State#state.escape)(State#state.host), + "';"]); add_sh_column(#state{dbtype = mysql} = State, Table) -> sql_query( State#state.host, @@ -292,6 +298,10 @@ drop_pkey(#state{dbtype = pgsql} = State, Table) -> sql_query( State#state.host, ["ALTER TABLE ", Table, " DROP CONSTRAINT ", Table, "_pkey;"]); +drop_pkey(#state{dbtype = mssql} = State, Table) -> + sql_query( + State#state.host, + ["ALTER TABLE [", Table, "] DROP CONSTRAINT [", Table, "_PRIMARY];"]); drop_pkey(#state{dbtype = mysql} = State, Table) -> sql_query( State#state.host, @@ -302,6 +312,13 @@ add_pkey(#state{dbtype = pgsql} = State, Table, Cols) -> sql_query( State#state.host, ["ALTER TABLE ", Table, " ADD PRIMARY KEY (", SCols, ");"]); +add_pkey(#state{dbtype = mssql} = State, Table, Cols) -> + SCols = string:join(Cols, "], ["), + sql_query( + State#state.host, + ["ALTER TABLE [", Table, "] ADD CONSTRAINT [", Table, "_PRIMARY] PRIMARY KEY CLUSTERED ([", SCols, "]) ", + "WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ", + "ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY];"]); add_pkey(#state{dbtype = mysql} = State, Table, Cols) -> Cols2 = [C ++ mysql_keylen(Table, C) || C <- Cols], SCols = string:join(Cols2, ", "), @@ -313,6 +330,10 @@ drop_sh_default(#state{dbtype = pgsql} = State, Table) -> sql_query( State#state.host, ["ALTER TABLE ", Table, " ALTER COLUMN server_host DROP DEFAULT;"]); +drop_sh_default(#state{dbtype = mssql} = State, Table) -> + sql_query( + State#state.host, + ["ALTER TABLE [", Table, "] DROP CONSTRAINT [server_host_default];"]); drop_sh_default(#state{dbtype = mysql} = State, Table) -> sql_query( State#state.host, @@ -322,6 +343,10 @@ drop_index(#state{dbtype = pgsql} = State, _Table, Index) -> sql_query( State#state.host, ["DROP INDEX ", Index, ";"]); +drop_index(#state{dbtype = mssql} = State, Table, Index) -> + sql_query( + State#state.host, + ["DROP INDEX [", mssql_old_index_name(Index), "] ON [", Table, "];"]); drop_index(#state{dbtype = mysql} = State, Table, Index) -> sql_query( State#state.host, @@ -333,6 +358,15 @@ create_unique_index(#state{dbtype = pgsql} = State, Table, Index, Cols) -> State#state.host, ["CREATE UNIQUE INDEX ", Index, " ON ", Table, " USING btree (", SCols, ");"]); +create_unique_index(#state{dbtype = mssql} = State, Table, "i_privacy_list_sh_username_name" = Index, Cols) -> + create_index(State, Table, Index, Cols); +create_unique_index(#state{dbtype = mssql} = State, Table, Index, Cols) -> + SCols = string:join(Cols, ", "), + sql_query( + State#state.host, + ["CREATE UNIQUE ", mssql_clustered(Index), "INDEX [", mssql_new_index_name(Index), "] ", + "ON [", Table, "] (", SCols, ") ", + "WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);"]); create_unique_index(#state{dbtype = mysql} = State, Table, Index, Cols) -> Cols2 = [C ++ mysql_keylen(Index, C) || C <- Cols], SCols = string:join(Cols2, ", "), @@ -347,6 +381,12 @@ create_index(#state{dbtype = pgsql} = State, Table, Index, Cols) -> State#state.host, ["CREATE INDEX ", Index, " ON ", Table, " USING btree (", SCols, ");"]); +create_index(#state{dbtype = mssql} = State, Table, Index, Cols) -> + SCols = string:join(Cols, ", "), + sql_query( + State#state.host, + ["CREATE INDEX [", mssql_new_index_name(Index), "] ON [", Table, "] (", SCols, ") ", + "WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);"]); create_index(#state{dbtype = mysql} = State, Table, Index, Cols) -> Cols2 = [C ++ mysql_keylen(Index, C) || C <- Cols], SCols = string:join(Cols2, ", "), @@ -355,6 +395,33 @@ create_index(#state{dbtype = mysql} = State, Table, Index, Cols) -> ["CREATE INDEX ", Index, " ON ", Table, "(", SCols, ");"]). +mssql_old_index_name("i_bare_peer") -> "archive_bare_peer"; +mssql_old_index_name("i_peer") -> "archive_peer"; +mssql_old_index_name("i_timestamp") -> "archive_timestamp"; +mssql_old_index_name("i_username") -> "archive_username"; +mssql_old_index_name("i_username_bare_peer") -> "archive_username_bare_peer"; +mssql_old_index_name("i_username_peer") -> "archive_username_peer"; +mssql_old_index_name("i_username_timestamp") -> "archive_username_timestamp"; +mssql_old_index_name("i_push_usn") -> "i_push_usn"; +mssql_old_index_name("i_push_ut") -> "i_push_ut"; +mssql_old_index_name("pk_rosterg_user_jid") -> "rostergroups_username_jid"; +mssql_old_index_name("i_rosteru_jid") -> "rosterusers_jid"; +mssql_old_index_name("i_rosteru_username") -> "rosterusers_username"; +mssql_old_index_name("i_rosteru_user_jid") -> "rosterusers_username_jid"; +mssql_old_index_name("i_despool") -> "spool_username"; +mssql_old_index_name("i_sr_user_jid_grp") -> "sr_user_jid_group"; +mssql_old_index_name(Index) -> string:substr(Index, 3). + +mssql_new_index_name("i_rosterg_sh_user_jid") -> "rostergroups_sh_username_jid"; +mssql_new_index_name("i_rosteru_sh_jid") -> "rosterusers_sh_jid"; +mssql_new_index_name("i_rosteru_sh_user_jid") -> "rosterusers_sh_username_jid"; +mssql_new_index_name("i_sr_user_sh_jid_grp") -> "sr_user_sh_jid_group"; +mssql_new_index_name(Index) -> string:substr(Index, 3). + +mssql_clustered("i_mix_pam") -> ""; +mssql_clustered("i_push_session_susn") -> ""; +mssql_clustered(_) -> "CLUSTERED ". + mysql_keylen(_, "bare_peer") -> "(191)"; mysql_keylen(_, "channel") -> "(191)"; mysql_keylen(_, "domain") -> "(75)"; @@ -389,5 +456,5 @@ mod_doc() -> ?T("This module can be used to update existing SQL database " "from the default to the new schema. Check the section " "http://../database/#default-and-new-schemas[Default and New Schemas] for details. " - "Please note that only MySQL and PostgreSQL are supported. " + "Please note that only MS SQL, MySQL, and PostgreSQL are supported. " "When the module is loaded use _`update_sql`_ API.")}. From d5bf051e79672691b14012c15f16245668a835c2 Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 19 Jan 2023 19:17:24 +0000 Subject: [PATCH 11/12] Fix minor SQL schema inconsistencies --- sql/lite.new.sql | 1 + sql/mssql.sql | 2 +- sql/mysql.new.sql | 1 + sql/mysql.old-to-new.sql | 4 ++-- sql/pg.new.sql | 4 ++++ sql/pg.sql | 2 +- 6 files changed, 10 insertions(+), 4 deletions(-) diff --git a/sql/lite.new.sql b/sql/lite.new.sql index 43baa0e1b..f48a393a0 100644 --- a/sql/lite.new.sql +++ b/sql/lite.new.sql @@ -414,6 +414,7 @@ CREATE TABLE push_session ( ); CREATE UNIQUE INDEX i_push_session_susn ON push_session (server_host, username, service, node); +CREATE INDEX i_push_session_sh_username_timestamp ON push_session (server_host, username, timestamp); CREATE TABLE mix_channel ( channel text NOT NULL, diff --git a/sql/mssql.sql b/sql/mssql.sql index 66c523e53..cf2f8b040 100644 --- a/sql/mssql.sql +++ b/sql/mssql.sql @@ -527,7 +527,7 @@ CREATE TABLE [dbo].[push_session] ( CREATE UNIQUE CLUSTERED INDEX [i_push_usn] ON [push_session] (username, service, node) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); -CREATE UNIQUE INDEX [i_push_ut] ON [push_session] (username, timestamp) +CREATE INDEX [i_push_ut] ON [push_session] (username, timestamp) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON); CREATE TABLE [dbo].[mix_channel] ( diff --git a/sql/mysql.new.sql b/sql/mysql.new.sql index 959fbff84..6254282d5 100644 --- a/sql/mysql.new.sql +++ b/sql/mysql.new.sql @@ -432,6 +432,7 @@ CREATE TABLE push_session ( ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE UNIQUE INDEX i_push_session_susn ON push_session (server_host(191), username(191), service(191), node(191)); +CREATE INDEX i_push_session_sh_username_timestamp ON push_session (server_host, username(191), timestamp); CREATE TABLE mix_channel ( channel text NOT NULL, diff --git a/sql/mysql.old-to-new.sql b/sql/mysql.old-to-new.sql index ae3ab490f..a58a90a46 100644 --- a/sql/mysql.old-to-new.sql +++ b/sql/mysql.old-to-new.sql @@ -17,6 +17,7 @@ BEGIN ALTER TABLE `push_session` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `push_session` ADD PRIMARY KEY (`server_host`, `username`(191), `timestamp`); ALTER TABLE `push_session` ADD UNIQUE INDEX `i_push_session_susn` (`server_host`, `username`(191), `service`(191), `node`(191)); + ALTER TABLE `push_session` ADD INDEX `i_push_session_sh_username_timestamp` (`server_host`, `username`(191), `timestamp`); ALTER TABLE `roster_version` DROP PRIMARY KEY; ALTER TABLE `roster_version` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `roster_version` ALTER COLUMN `server_host` DROP DEFAULT; @@ -73,10 +74,10 @@ BEGIN ALTER TABLE `last` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `username`; ALTER TABLE `last` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `last` ADD PRIMARY KEY (`server_host`, `username`); + ALTER TABLE `sr_group` DROP INDEX `i_sr_group_name`; ALTER TABLE `sr_group` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `name`; ALTER TABLE `sr_group` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `sr_group` ADD UNIQUE INDEX `i_sr_group_sh_name` (`server_host`, `name`); - ALTER TABLE `sr_group` ADD PRIMARY KEY (`server_host`, `name`); ALTER TABLE `muc_registered` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `host`; ALTER TABLE `muc_registered` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `sm` DROP INDEX `i_node`; @@ -99,7 +100,6 @@ BEGIN ALTER TABLE `sr_user` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `sr_user` ADD UNIQUE INDEX `i_sr_user_sh_jid_group` (`server_host`, `jid`, `grp`); ALTER TABLE `sr_user` ADD INDEX `i_sr_user_sh_grp` (`server_host`, `grp`); - ALTER TABLE `sr_user` ADD PRIMARY KEY (`server_host`, `jid`, `grp`); ALTER TABLE `muc_online_users` ADD COLUMN `server_host` VARCHAR (191) COLLATE `utf8mb4_unicode_ci` NOT NULL DEFAULT @DEFAULT_HOST AFTER `host`; ALTER TABLE `muc_online_users` ALTER COLUMN `server_host` DROP DEFAULT; ALTER TABLE `vcard` DROP PRIMARY KEY; diff --git a/sql/pg.new.sql b/sql/pg.new.sql index f3888da07..32246d3f6 100644 --- a/sql/pg.new.sql +++ b/sql/pg.new.sql @@ -41,7 +41,9 @@ -- ALTER TABLE rostergroups ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE sr_group ADD COLUMN server_host text NOT NULL DEFAULT ''; +-- DROP INDEX i_sr_group_name; -- ALTER TABLE sr_group ADD PRIMARY KEY (server_host, name); +-- CREATE UNIQUE INDEX i_sr_group_sh_name ON sr_group USING btree (server_host, name); -- ALTER TABLE sr_group ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE sr_user ADD COLUMN server_host text NOT NULL DEFAULT ''; @@ -153,6 +155,7 @@ -- 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); +-- CREATE INDEX i_push_session_sh_username_timestamp ON push_session USING btree (server_host, username, timestamp); -- ALTER TABLE push_session ALTER COLUMN server_host DROP DEFAULT; -- ALTER TABLE mix_pam ADD COLUMN server_host text NOT NULL DEFAULT ''; @@ -583,6 +586,7 @@ CREATE TABLE push_session ( ); CREATE UNIQUE INDEX i_push_session_susn ON push_session USING btree (server_host, username, service, node); +CREATE INDEX i_push_session_sh_username_timestamp ON push_session USING btree (server_host, username, timestamp); CREATE TABLE mix_channel ( channel text NOT NULL, diff --git a/sql/pg.sql b/sql/pg.sql index 5a0d4b766..fe244c757 100644 --- a/sql/pg.sql +++ b/sql/pg.sql @@ -403,7 +403,7 @@ CREATE TABLE push_session ( ); CREATE UNIQUE INDEX i_push_usn ON push_session USING btree (username, service, node); -CREATE UNIQUE INDEX i_push_ut ON push_session USING btree (username, timestamp); +CREATE INDEX i_push_ut ON push_session USING btree (username, timestamp); CREATE TABLE mix_channel ( channel text NOT NULL, From 4f0e426a12aadc6a7249e6a8d6fe62cdb0579cd7 Mon Sep 17 00:00:00 2001 From: Stu Tomlinson Date: Thu, 19 Jan 2023 23:33:46 +0000 Subject: [PATCH 12/12] Change PostgreSQL SERIAL to BIGSERIAL columns This is consistent with other schemas, internally consistent with foreign keys, and allows for > 2B records in these tables. --- sql/pg.new.sql | 10 +++++----- sql/pg.sql | 10 +++++----- 2 files changed, 10 insertions(+), 10 deletions(-) diff --git a/sql/pg.new.sql b/sql/pg.new.sql index 32246d3f6..ba0dc31dd 100644 --- a/sql/pg.new.sql +++ b/sql/pg.new.sql @@ -244,7 +244,7 @@ CREATE TABLE spool ( username text NOT NULL, server_host text NOT NULL, xml text NOT NULL, - seq SERIAL, + seq BIGSERIAL, created_at TIMESTAMP NOT NULL DEFAULT now() ); @@ -258,7 +258,7 @@ CREATE TABLE archive ( bare_peer text NOT NULL, xml text NOT NULL, txt text, - id SERIAL, + id BIGSERIAL, kind text, nick text, created_at TIMESTAMP NOT NULL DEFAULT now() @@ -339,7 +339,7 @@ CREATE TABLE privacy_list ( username text NOT NULL, server_host text NOT NULL, name text NOT NULL, - id SERIAL UNIQUE, + id BIGSERIAL UNIQUE, created_at TIMESTAMP NOT NULL DEFAULT now() ); @@ -394,7 +394,7 @@ CREATE TABLE pubsub_node ( node text NOT NULL, parent text NOT NULL DEFAULT '', plugin text NOT NULL, - nodeid SERIAL UNIQUE + nodeid BIGSERIAL UNIQUE ); CREATE INDEX i_pubsub_node_parent ON pubsub_node USING btree (parent); CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node USING btree (host, node); @@ -417,7 +417,7 @@ CREATE TABLE pubsub_state ( jid text NOT NULL, affiliation character(1), subscriptions text NOT NULL DEFAULT '', - stateid SERIAL UNIQUE + stateid BIGSERIAL UNIQUE ); CREATE INDEX i_pubsub_state_jid ON pubsub_state USING btree (jid); CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state USING btree (nodeid, jid); diff --git a/sql/pg.sql b/sql/pg.sql index fe244c757..813e690dd 100644 --- a/sql/pg.sql +++ b/sql/pg.sql @@ -82,7 +82,7 @@ CREATE INDEX i_sr_user_grp ON sr_user USING btree (grp); CREATE TABLE spool ( username text NOT NULL, xml text NOT NULL, - seq SERIAL, + seq BIGSERIAL, created_at TIMESTAMP NOT NULL DEFAULT now() ); @@ -95,7 +95,7 @@ CREATE TABLE archive ( bare_peer text NOT NULL, xml text NOT NULL, txt text, - id SERIAL, + id BIGSERIAL, kind text, nick text, created_at TIMESTAMP NOT NULL DEFAULT now() @@ -167,7 +167,7 @@ CREATE TABLE privacy_default_list ( CREATE TABLE privacy_list ( username text NOT NULL, name text NOT NULL, - id SERIAL UNIQUE, + id BIGSERIAL UNIQUE, created_at TIMESTAMP NOT NULL DEFAULT now() ); @@ -220,7 +220,7 @@ CREATE TABLE pubsub_node ( node text NOT NULL, parent text NOT NULL DEFAULT '', plugin text NOT NULL, - nodeid SERIAL UNIQUE + nodeid BIGSERIAL UNIQUE ); CREATE INDEX i_pubsub_node_parent ON pubsub_node USING btree (parent); CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node USING btree (host, node); @@ -243,7 +243,7 @@ CREATE TABLE pubsub_state ( jid text NOT NULL, affiliation character(1), subscriptions text NOT NULL DEFAULT '', - stateid SERIAL UNIQUE + stateid BIGSERIAL UNIQUE ); CREATE INDEX i_pubsub_state_jid ON pubsub_state USING btree (jid); CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state USING btree (nodeid, jid);