mirror of
https://github.com/processone/ejabberd.git
synced 2024-12-22 17:28:25 +01:00
Add MS SQL support for new schema migration
This commit is contained in:
parent
f7f0d3b1fb
commit
c7c982b67b
@ -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.")}.
|
||||
|
Loading…
Reference in New Issue
Block a user