mirror of
https://github.com/processone/ejabberd.git
synced 2024-10-03 14:45:16 +02:00
Add SQL_INSERT macro and update SQL queries to use server_host field
This commit is contained in:
parent
354a710e70
commit
78dfb832b8
@ -84,6 +84,14 @@ AC_ARG_ENABLE(roster_gateway_workaround,
|
||||
*) AC_MSG_ERROR(bad value ${enableval} for --enable-roster-gateway-workaround) ;;
|
||||
esac],[roster_gateway_workaround=false])
|
||||
|
||||
AC_ARG_ENABLE(new_sql_schema,
|
||||
[AC_HELP_STRING([--enable-new-sql-schema], [use new SQL schema (default: no)])],
|
||||
[case "${enableval}" in
|
||||
yes) new_sql_schema=true ;;
|
||||
no) new_sql_schema=false ;;
|
||||
*) AC_MSG_ERROR(bad value ${enableval} for --enable-new-sql-schema) ;;
|
||||
esac],[new_sql_schema=false])
|
||||
|
||||
AC_ARG_ENABLE(full_xml,
|
||||
[AC_HELP_STRING([--enable-full-xml], [use XML features in XMPP stream (ex: CDATA) (default: no, requires XML compliant clients)])],
|
||||
[case "${enableval}" in
|
||||
@ -273,6 +281,7 @@ fi
|
||||
|
||||
AC_SUBST(hipe)
|
||||
AC_SUBST(roster_gateway_workaround)
|
||||
AC_SUBST(new_sql_schema)
|
||||
AC_SUBST(full_xml)
|
||||
AC_SUBST(db_type)
|
||||
AC_SUBST(odbc)
|
||||
|
@ -27,6 +27,9 @@
|
||||
-define(SQL_UPSERT_T(Table, Fields),
|
||||
ejabberd_sql:sql_query_t(?SQL_UPSERT_MARK(Table, Fields))).
|
||||
|
||||
-define(SQL_INSERT_MARK, sql_insert__mark_).
|
||||
-define(SQL_INSERT(Table, Fields), ?SQL_INSERT_MARK(Table, Fields)).
|
||||
|
||||
-record(sql_query, {hash, format_query, format_res, args, loc}).
|
||||
|
||||
-record(sql_escape, {string, integer, boolean}).
|
||||
|
@ -99,6 +99,7 @@
|
||||
{if_have_fun, {rand, uniform, 1}, {d, 'RAND_UNIFORM'}},
|
||||
{if_have_fun, {gb_sets, iterator_from, 2}, {d, 'GB_SETS_ITERATOR_FROM'}},
|
||||
{if_have_fun, {public_key, short_name_hash, 1}, {d, 'SHORT_NAME_HASH'}},
|
||||
{if_var_true, new_sql_schema, {d, 'NEW_SQL_SCHEMA'}},
|
||||
{if_var_true, hipe, native},
|
||||
{src_dirs, [asn1, src,
|
||||
{if_var_true, tools, tools},
|
||||
|
604
sql/pg.new.sql
Normal file
604
sql/pg.new.sql
Normal file
@ -0,0 +1,604 @@
|
||||
--
|
||||
-- ejabberd, Copyright (C) 2002-2017 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.
|
||||
--
|
||||
|
||||
-- To update from the old schema, replace <HOST> with the host's domain:
|
||||
|
||||
-- ALTER TABLE users ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE users DROP CONSTRAINT users_pkey;
|
||||
-- ALTER TABLE users ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE users ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE last ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE last DROP CONSTRAINT last_pkey;
|
||||
-- ALTER TABLE last ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE last ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE rosterusers ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- 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;
|
||||
|
||||
-- ALTER TABLE rostergroups ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- DROP INDEX pk_rosterg_user_jid;
|
||||
-- CREATE INDEX i_rosterg_sh_user_jid ON rostergroups USING btree (server_host, username, jid);
|
||||
-- ALTER TABLE rostergroups ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE sr_group ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE sr_group ADD PRIMARY KEY (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 '<HOST>';
|
||||
-- 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;
|
||||
|
||||
-- ALTER TABLE spool ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- DROP INDEX i_despool;
|
||||
-- CREATE INDEX i_spool_sh_username ON spool USING btree (server_host, username);
|
||||
-- ALTER TABLE spool ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE archive ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- DROP INDEX i_username;
|
||||
-- DROP INDEX i_username_timestamp;
|
||||
-- DROP INDEX i_timestamp;
|
||||
-- DROP INDEX i_peer;
|
||||
-- DROP INDEX i_bare_peer;
|
||||
-- CREATE INDEX i_archive_sh_username_timestamp ON archive USING btree (server_host, username, timestamp);
|
||||
-- CREATE INDEX i_archive_sh_timestamp ON archive USING btree (server_host, timestamp);
|
||||
-- CREATE INDEX i_archive_sh_peer ON archive USING btree (server_host, peer);
|
||||
-- CREATE INDEX i_archive_sh_bare_peer ON archive USING btree (server_host, bare_peer);
|
||||
-- ALTER TABLE archive ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE archive_prefs ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE archive_prefs DROP CONSTRAINT archive_prefs_pkey;
|
||||
-- ALTER TABLE archive_prefs ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE archive_prefs ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE vcard ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE vcard DROP CONSTRAINT vcard_pkey;
|
||||
-- ALTER TABLE vcard ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE vcard ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE vcard_search ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE vcard_search DROP CONSTRAINT vcard_search_pkey;
|
||||
-- DROP INDEX i_vcard_search_lfn;
|
||||
-- DROP INDEX i_vcard_search_lfamily;
|
||||
-- DROP INDEX i_vcard_search_lgiven;
|
||||
-- DROP INDEX i_vcard_search_lmiddle;
|
||||
-- DROP INDEX i_vcard_search_lnickname;
|
||||
-- DROP INDEX i_vcard_search_lbday;
|
||||
-- DROP INDEX i_vcard_search_lctry;
|
||||
-- DROP INDEX i_vcard_search_llocality;
|
||||
-- DROP INDEX i_vcard_search_lemail;
|
||||
-- DROP INDEX i_vcard_search_lorgname;
|
||||
-- DROP INDEX i_vcard_search_lorgunit;
|
||||
-- ALTER TABLE vcard_search ADD PRIMARY KEY (server_host, username);
|
||||
-- CREATE INDEX i_vcard_search_sh_lfn ON vcard_search(server_host, lfn);
|
||||
-- CREATE INDEX i_vcard_search_sh_lfamily ON vcard_search(server_host, lfamily);
|
||||
-- CREATE INDEX i_vcard_search_sh_lgiven ON vcard_search(server_host, lgiven);
|
||||
-- CREATE INDEX i_vcard_search_sh_lmiddle ON vcard_search(server_host, lmiddle);
|
||||
-- CREATE INDEX i_vcard_search_sh_lnickname ON vcard_search(server_host, lnickname);
|
||||
-- CREATE INDEX i_vcard_search_sh_lbday ON vcard_search(server_host, lbday);
|
||||
-- CREATE INDEX i_vcard_search_sh_lctry ON vcard_search(server_host, lctry);
|
||||
-- CREATE INDEX i_vcard_search_sh_llocality ON vcard_search(server_host, llocality);
|
||||
-- CREATE INDEX i_vcard_search_sh_lemail ON vcard_search(server_host, lemail);
|
||||
-- CREATE INDEX i_vcard_search_sh_lorgname ON vcard_search(server_host, lorgname);
|
||||
-- CREATE INDEX i_vcard_search_sh_lorgunit ON vcard_search(server_host, lorgunit);
|
||||
-- ALTER TABLE vcard_search ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE privacy_default_list ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE privacy_default_list DROP CONSTRAINT privacy_default_list_pkey;
|
||||
-- ALTER TABLE privacy_default_list ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE privacy_default_list ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE privacy_list ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- 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 '<HOST>';
|
||||
-- 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 '<HOST>';
|
||||
-- ALTER TABLE roster_version DROP CONSTRAINT roster_version_pkey;
|
||||
-- ALTER TABLE roster_version ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE roster_version ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE muc_room ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE muc_room ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE muc_registered ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE muc_registered ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE muc_online_room ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE muc_online_room ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE muc_online_users ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE muc_online_users ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE irc_custom ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE irc_custom ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE motd ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- ALTER TABLE motd DROP CONSTRAINT motd_pkey;
|
||||
-- ALTER TABLE motd ADD PRIMARY KEY (server_host, username);
|
||||
-- ALTER TABLE motd ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE sm ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- DROP INDEX i_sm_sid;
|
||||
-- DROP INDEX i_sm_username;
|
||||
-- ALTER TABLE sm ADD PRIMARY KEY (usec, pid);
|
||||
-- CREATE INDEX i_sm_sh_username ON sm USING btree (server_host, username);
|
||||
-- ALTER TABLE sm ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
-- ALTER TABLE carboncopy ADD COLUMN server_host text NOT NULL DEFAULT '<HOST>';
|
||||
-- DROP INDEX i_carboncopy_ur;
|
||||
-- DROP INDEX i_carboncopy_user;
|
||||
-- ALTER TABLE carboncopy ADD PRIMARY KEY (server_host, username, resource);
|
||||
-- CREATE INDEX i_carboncopy_sh_user ON carboncopy USING btree (server_host, username);
|
||||
-- ALTER TABLE carboncopy ALTER COLUMN server_host DROP DEFAULT;
|
||||
|
||||
|
||||
CREATE TABLE users (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
"password" text NOT NULL,
|
||||
serverkey text NOT NULL DEFAULT '',
|
||||
salt text NOT NULL DEFAULT '',
|
||||
iterationcount integer NOT NULL DEFAULT 0,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now(),
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
-- Add support for SCRAM auth to a database created before ejabberd 16.03:
|
||||
-- ALTER TABLE users ADD COLUMN serverkey text NOT NULL DEFAULT '';
|
||||
-- ALTER TABLE users ADD COLUMN salt text NOT NULL DEFAULT '';
|
||||
-- ALTER TABLE users ADD COLUMN iterationcount integer NOT NULL DEFAULT 0;
|
||||
|
||||
CREATE TABLE last (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
seconds text NOT NULL,
|
||||
state text NOT NULL,
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE rosterusers (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
jid text NOT NULL,
|
||||
nick text NOT NULL,
|
||||
subscription character(1) NOT NULL,
|
||||
ask character(1) NOT NULL,
|
||||
askmessage text NOT NULL,
|
||||
server character(1) NOT NULL,
|
||||
subscribe text NOT NULL,
|
||||
"type" text,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
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);
|
||||
|
||||
|
||||
CREATE TABLE rostergroups (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
jid text NOT NULL,
|
||||
grp text NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX i_rosterg_sh_user_jid ON rostergroups USING btree (server_host, username, jid);
|
||||
|
||||
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)
|
||||
);
|
||||
|
||||
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)
|
||||
);
|
||||
|
||||
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 (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
xml text NOT NULL,
|
||||
seq SERIAL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX i_spool_sh_username ON spool USING btree (server_host, username);
|
||||
|
||||
CREATE TABLE archive (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
timestamp BIGINT NOT NULL,
|
||||
peer text NOT NULL,
|
||||
bare_peer text NOT NULL,
|
||||
xml text NOT NULL,
|
||||
txt text,
|
||||
id SERIAL,
|
||||
kind text,
|
||||
nick text,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX i_archive_sh_username_timestamp ON archive USING btree (server_host, username, timestamp);
|
||||
CREATE INDEX i_archive_sh_timestamp ON archive USING btree (server_host, timestamp);
|
||||
CREATE INDEX i_archive_sh_peer ON archive USING btree (server_host, peer);
|
||||
CREATE INDEX i_archive_sh_bare_peer ON archive USING btree (server_host, bare_peer);
|
||||
|
||||
CREATE TABLE archive_prefs (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
def text NOT NULL,
|
||||
always text NOT NULL,
|
||||
never text NOT NULL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now(),
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
CREATE TABLE vcard (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
vcard text NOT NULL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now(),
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
CREATE TABLE vcard_search (
|
||||
username text NOT NULL,
|
||||
lusername text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
fn text NOT NULL,
|
||||
lfn text NOT NULL,
|
||||
family text NOT NULL,
|
||||
lfamily text NOT NULL,
|
||||
given text NOT NULL,
|
||||
lgiven text NOT NULL,
|
||||
middle text NOT NULL,
|
||||
lmiddle text NOT NULL,
|
||||
nickname text NOT NULL,
|
||||
lnickname text NOT NULL,
|
||||
bday text NOT NULL,
|
||||
lbday text NOT NULL,
|
||||
ctry text NOT NULL,
|
||||
lctry text NOT NULL,
|
||||
locality text NOT NULL,
|
||||
llocality text NOT NULL,
|
||||
email text NOT NULL,
|
||||
lemail text NOT NULL,
|
||||
orgname text NOT NULL,
|
||||
lorgname text NOT NULL,
|
||||
orgunit text NOT NULL,
|
||||
lorgunit text NOT NULL,
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
CREATE INDEX i_vcard_search_sh_lfn ON vcard_search(server_host, lfn);
|
||||
CREATE INDEX i_vcard_search_sh_lfamily ON vcard_search(server_host, lfamily);
|
||||
CREATE INDEX i_vcard_search_sh_lgiven ON vcard_search(server_host, lgiven);
|
||||
CREATE INDEX i_vcard_search_sh_lmiddle ON vcard_search(server_host, lmiddle);
|
||||
CREATE INDEX i_vcard_search_sh_lnickname ON vcard_search(server_host, lnickname);
|
||||
CREATE INDEX i_vcard_search_sh_lbday ON vcard_search(server_host, lbday);
|
||||
CREATE INDEX i_vcard_search_sh_lctry ON vcard_search(server_host, lctry);
|
||||
CREATE INDEX i_vcard_search_sh_llocality ON vcard_search(server_host, llocality);
|
||||
CREATE INDEX i_vcard_search_sh_lemail ON vcard_search(server_host, lemail);
|
||||
CREATE INDEX i_vcard_search_sh_lorgname ON vcard_search(server_host, lorgname);
|
||||
CREATE INDEX i_vcard_search_sh_lorgunit ON vcard_search(server_host, lorgunit);
|
||||
|
||||
CREATE TABLE privacy_default_list (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
name text NOT NULL,
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
CREATE TABLE privacy_list (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
name text NOT NULL,
|
||||
id SERIAL UNIQUE,
|
||||
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 (
|
||||
id bigint REFERENCES privacy_list(id) ON DELETE CASCADE,
|
||||
t character(1) NOT NULL,
|
||||
value text NOT NULL,
|
||||
action character(1) NOT NULL,
|
||||
ord NUMERIC NOT NULL,
|
||||
match_all boolean NOT NULL,
|
||||
match_iq boolean NOT NULL,
|
||||
match_message boolean NOT NULL,
|
||||
match_presence_in boolean NOT NULL,
|
||||
match_presence_out boolean NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX i_privacy_list_data_id ON privacy_list_data USING btree (id);
|
||||
|
||||
CREATE TABLE private_storage (
|
||||
username text NOT NULL,
|
||||
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)
|
||||
);
|
||||
|
||||
CREATE INDEX i_private_storage_sh_username ON private_storage USING btree (server_host, username);
|
||||
|
||||
|
||||
CREATE TABLE roster_version (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
version text NOT NULL,
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
-- To update from 0.9.8:
|
||||
-- CREATE SEQUENCE spool_seq_seq;
|
||||
-- ALTER TABLE spool ADD COLUMN seq integer;
|
||||
-- ALTER TABLE spool ALTER COLUMN seq SET DEFAULT nextval('spool_seq_seq');
|
||||
-- UPDATE spool SET seq = DEFAULT;
|
||||
-- ALTER TABLE spool ALTER COLUMN seq SET NOT NULL;
|
||||
|
||||
-- To update from 1.x:
|
||||
-- ALTER TABLE rosterusers ADD COLUMN askmessage text;
|
||||
-- UPDATE rosterusers SET askmessage = '';
|
||||
-- ALTER TABLE rosterusers ALTER COLUMN askmessage SET NOT NULL;
|
||||
|
||||
CREATE TABLE pubsub_node (
|
||||
host text NOT NULL,
|
||||
node text NOT NULL,
|
||||
parent text NOT NULL DEFAULT '',
|
||||
"type" text NOT NULL,
|
||||
nodeid SERIAL 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);
|
||||
|
||||
CREATE TABLE pubsub_node_option (
|
||||
nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
|
||||
name text NOT NULL,
|
||||
val text NOT NULL
|
||||
);
|
||||
CREATE INDEX i_pubsub_node_option_nodeid ON pubsub_node_option USING btree (nodeid);
|
||||
|
||||
CREATE TABLE pubsub_node_owner (
|
||||
nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
|
||||
owner text NOT NULL
|
||||
);
|
||||
CREATE INDEX i_pubsub_node_owner_nodeid ON pubsub_node_owner USING btree (nodeid);
|
||||
|
||||
CREATE TABLE pubsub_state (
|
||||
nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
|
||||
jid text NOT NULL,
|
||||
affiliation character(1),
|
||||
subscriptions text NOT NULL DEFAULT '',
|
||||
stateid SERIAL 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);
|
||||
|
||||
CREATE TABLE pubsub_item (
|
||||
nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
|
||||
itemid text NOT NULL,
|
||||
publisher text NOT NULL,
|
||||
creation text NOT NULL,
|
||||
modification text NOT NULL,
|
||||
payload text NOT NULL DEFAULT ''
|
||||
);
|
||||
CREATE INDEX i_pubsub_item_itemid ON pubsub_item USING btree (itemid);
|
||||
CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item USING btree (nodeid, itemid);
|
||||
|
||||
CREATE TABLE pubsub_subscription_opt (
|
||||
subid text NOT NULL,
|
||||
opt_name varchar(32),
|
||||
opt_value text NOT NULL
|
||||
);
|
||||
CREATE UNIQUE INDEX i_pubsub_subscription_opt ON pubsub_subscription_opt USING btree (subid, opt_name);
|
||||
|
||||
CREATE TABLE muc_room (
|
||||
name text NOT NULL,
|
||||
host text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
opts text NOT NULL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_muc_room_name_host ON muc_room USING btree (name, host);
|
||||
|
||||
CREATE TABLE muc_registered (
|
||||
jid text NOT NULL,
|
||||
host text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
nick text NOT NULL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX i_muc_registered_nick ON muc_registered USING btree (nick);
|
||||
CREATE UNIQUE INDEX i_muc_registered_jid_host ON muc_registered USING btree (jid, host);
|
||||
|
||||
CREATE TABLE muc_online_room (
|
||||
name text NOT NULL,
|
||||
host text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
node text NOT NULL,
|
||||
pid text NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_muc_online_room_name_host ON muc_online_room USING btree (name, host);
|
||||
|
||||
CREATE TABLE muc_online_users (
|
||||
username text NOT NULL,
|
||||
server text NOT NULL,
|
||||
resource text NOT NULL,
|
||||
name text NOT NULL,
|
||||
host text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
node text NOT NULL
|
||||
);
|
||||
|
||||
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,
|
||||
host text NOT NULL,
|
||||
jid text NOT NULL,
|
||||
nick text NOT NULL,
|
||||
nodes text NOT NULL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX i_muc_room_subscribers_host_jid ON muc_room_subscribers USING btree (host, jid);
|
||||
CREATE UNIQUE INDEX i_muc_room_subscribers_host_room_jid ON muc_room_subscribers USING btree (host, room, jid);
|
||||
|
||||
CREATE TABLE irc_custom (
|
||||
jid text NOT NULL,
|
||||
host text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
data text NOT NULL,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_irc_custom_jid_host ON irc_custom USING btree (jid, host);
|
||||
|
||||
CREATE TABLE motd (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
xml text,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now(),
|
||||
PRIMARY KEY (server_host, username)
|
||||
);
|
||||
|
||||
CREATE TABLE caps_features (
|
||||
node text NOT NULL,
|
||||
subnode text NOT NULL,
|
||||
feature text,
|
||||
created_at TIMESTAMP NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX i_caps_features_node_subnode ON caps_features USING btree (node, subnode);
|
||||
|
||||
CREATE TABLE sm (
|
||||
usec bigint NOT NULL,
|
||||
pid text NOT NULL,
|
||||
node text NOT NULL,
|
||||
username text NOT NULL,
|
||||
resource text NOT NULL,
|
||||
priority text NOT NULL,
|
||||
info text NOT NULL,
|
||||
PRIMARY KEY (usec, pid)
|
||||
);
|
||||
|
||||
CREATE INDEX i_sm_node ON sm USING btree (node);
|
||||
CREATE INDEX i_sm_sh_username ON sm USING btree (server_host, username);
|
||||
|
||||
CREATE TABLE oauth_token (
|
||||
token text NOT NULL,
|
||||
jid text NOT NULL,
|
||||
scope text NOT NULL,
|
||||
expire bigint NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_oauth_token_token ON oauth_token USING btree (token);
|
||||
|
||||
CREATE TABLE route (
|
||||
domain text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
node text NOT NULL,
|
||||
pid text NOT NULL,
|
||||
local_hint text NOT NULL
|
||||
);
|
||||
|
||||
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,
|
||||
node text NOT NULL,
|
||||
pid text NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_bosh_sid ON bosh USING btree (sid);
|
||||
|
||||
CREATE TABLE carboncopy (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
resource text NOT NULL,
|
||||
namespace text NOT NULL,
|
||||
node text NOT NULL,
|
||||
PRIMARY KEY (server_host, username, resource)
|
||||
);
|
||||
|
||||
CREATE INDEX i_carboncopy_sh_user ON carboncopy USING btree (server_host, username);
|
||||
|
||||
CREATE TABLE proxy65 (
|
||||
sid text NOT NULL,
|
||||
pid_t text NOT NULL,
|
||||
pid_i text NOT NULL,
|
||||
node_t text NOT NULL,
|
||||
node_i text NOT NULL,
|
||||
jid_i text NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_proxy65_sid ON proxy65 USING btree (sid);
|
||||
CREATE INDEX i_proxy65_jid ON proxy65 USING btree (jid_i);
|
||||
|
||||
CREATE TABLE push_session (
|
||||
username text NOT NULL,
|
||||
server_host text NOT NULL,
|
||||
timestamp bigint NOT NULL,
|
||||
service text NOT NULL,
|
||||
node text NOT NULL,
|
||||
xml text NOT NULL,
|
||||
PRIMARY KEY (server_host, username, timestamp)
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX i_push_session_susn ON push_session USING btree (server_host, username, service, node);
|
@ -40,7 +40,6 @@
|
||||
|
||||
-include("ejabberd.hrl").
|
||||
-include("logger.hrl").
|
||||
-include("ejabberd_sql_pt.hrl").
|
||||
-include("ejabberd_auth.hrl").
|
||||
|
||||
-record(reg_users_counter, {vhost = <<"">> :: binary(),
|
||||
|
@ -106,9 +106,12 @@ export(_Server) ->
|
||||
[{passwd,
|
||||
fun(Host, #passwd{us = {LUser, LServer}, password = Password})
|
||||
when LServer == Host ->
|
||||
[?SQL("delete from users where username=%(LUser)s;"),
|
||||
?SQL("insert into users(username, password) "
|
||||
"values (%(LUser)s, %(Password)s);")];
|
||||
[?SQL("delete from users where username=%(LUser)s and %(LServer)H;"),
|
||||
?SQL_INSERT(
|
||||
"users",
|
||||
["username=%(LUser)s",
|
||||
"server_host=%(LServer)s",
|
||||
"password=%(Password)s"])];
|
||||
(_Host, _R) ->
|
||||
[]
|
||||
end}].
|
||||
|
@ -61,11 +61,11 @@ set_password(User, Server, Password) ->
|
||||
F = fun() ->
|
||||
if is_record(Password, scram) ->
|
||||
set_password_scram_t(
|
||||
User,
|
||||
User, Server,
|
||||
Password#scram.storedkey, Password#scram.serverkey,
|
||||
Password#scram.salt, Password#scram.iterationcount);
|
||||
true ->
|
||||
set_password_t(User, Password)
|
||||
set_password_t(User, Server, Password)
|
||||
end
|
||||
end,
|
||||
case ejabberd_sql:sql_transaction(Server, F) of
|
||||
@ -133,20 +133,22 @@ remove_user(User, Server) ->
|
||||
|
||||
-define(BATCH_SIZE, 1000).
|
||||
|
||||
set_password_scram_t(LUser,
|
||||
set_password_scram_t(LUser, LServer,
|
||||
StoredKey, ServerKey, Salt, IterationCount) ->
|
||||
?SQL_UPSERT_T(
|
||||
"users",
|
||||
["!username=%(LUser)s",
|
||||
"!server_host=%(LServer)s",
|
||||
"password=%(StoredKey)s",
|
||||
"serverkey=%(ServerKey)s",
|
||||
"salt=%(Salt)s",
|
||||
"iterationcount=%(IterationCount)d"]).
|
||||
|
||||
set_password_t(LUser, Password) ->
|
||||
set_password_t(LUser, LServer, Password) ->
|
||||
?SQL_UPSERT_T(
|
||||
"users",
|
||||
["!username=%(LUser)s",
|
||||
"!server_host=%(LServer)s",
|
||||
"password=%(Password)s"]).
|
||||
|
||||
get_password_scram(LServer, LUser) ->
|
||||
@ -154,32 +156,39 @@ get_password_scram(LServer, LUser) ->
|
||||
LServer,
|
||||
?SQL("select @(password)s, @(serverkey)s, @(salt)s, @(iterationcount)d"
|
||||
" from users"
|
||||
" where username=%(LUser)s")).
|
||||
" where username=%(LUser)s and %(LServer)H")).
|
||||
|
||||
add_user_scram(LServer, LUser,
|
||||
StoredKey, ServerKey, Salt, IterationCount) ->
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("insert into users(username, password, serverkey, salt, "
|
||||
"iterationcount) "
|
||||
"values (%(LUser)s, %(StoredKey)s, %(ServerKey)s,"
|
||||
" %(Salt)s, %(IterationCount)d)")).
|
||||
?SQL_INSERT(
|
||||
"users",
|
||||
["username=%(LUser)s",
|
||||
"server_host=%(LServer)s",
|
||||
"password=%(StoredKey)s",
|
||||
"serverkey=%(ServerKey)s",
|
||||
"salt=%(Salt)s",
|
||||
"iterationcount=%(IterationCount)d"])).
|
||||
|
||||
add_user(LServer, LUser, Password) ->
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("insert into users(username, password) "
|
||||
"values (%(LUser)s, %(Password)s)")).
|
||||
?SQL_INSERT(
|
||||
"users",
|
||||
["username=%(LUser)s",
|
||||
"server_host=%(LServer)s",
|
||||
"password=%(Password)s"])).
|
||||
|
||||
del_user(LServer, LUser) ->
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("delete from users where username=%(LUser)s")).
|
||||
?SQL("delete from users where username=%(LUser)s and %(LServer)H")).
|
||||
|
||||
list_users(LServer, []) ->
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("select @(username)s from users"));
|
||||
?SQL("select @(username)s from users where %(LServer)H"));
|
||||
list_users(LServer, [{from, Start}, {to, End}])
|
||||
when is_integer(Start) and is_integer(End) ->
|
||||
list_users(LServer,
|
||||
@ -196,6 +205,7 @@ list_users(LServer, [{limit, Limit}, {offset, Offset}])
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("select @(username)s from users "
|
||||
"where %(LServer)H "
|
||||
"order by username "
|
||||
"limit %(Limit)d offset %(Offset)d"));
|
||||
list_users(LServer,
|
||||
@ -207,7 +217,7 @@ list_users(LServer,
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("select @(username)s from users "
|
||||
"where username like %(SPrefix2)s escape '^' "
|
||||
"where username like %(SPrefix2)s escape '^' and %(LServer)H "
|
||||
"order by username "
|
||||
"limit %(Limit)d offset %(Offset)d")).
|
||||
|
||||
@ -224,11 +234,11 @@ users_number(LServer) ->
|
||||
" where oid = 'users'::regclass::oid"));
|
||||
_ ->
|
||||
ejabberd_sql:sql_query_t(
|
||||
?SQL("select @(count(*))d from users"))
|
||||
?SQL("select @(count(*))d from users where %(LServer)H"))
|
||||
end;
|
||||
(_Type, _) ->
|
||||
ejabberd_sql:sql_query_t(
|
||||
?SQL("select @(count(*))d from users"))
|
||||
?SQL("select @(count(*))d from users where %(LServer)H"))
|
||||
end).
|
||||
|
||||
users_number(LServer, [{prefix, Prefix}])
|
||||
@ -238,7 +248,7 @@ users_number(LServer, [{prefix, Prefix}])
|
||||
ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("select @(count(*))d from users "
|
||||
"where username like %(SPrefix2)s escape '^'"));
|
||||
"where username like %(SPrefix2)s escape '^' and %(LServer)H"));
|
||||
users_number(LServer, []) ->
|
||||
users_number(LServer).
|
||||
|
||||
@ -254,7 +264,7 @@ convert_to_scram(Server) ->
|
||||
case ejabberd_sql:sql_query_t(
|
||||
?SQL("select @(username)s, @(password)s"
|
||||
" from users"
|
||||
" where iterationcount=0"
|
||||
" where iterationcount=0 and %(LServer)H"
|
||||
" limit %(BatchSize)d")) of
|
||||
{selected, []} ->
|
||||
ok;
|
||||
@ -270,7 +280,7 @@ convert_to_scram(Server) ->
|
||||
_ ->
|
||||
Scram = ejabberd_auth:password_to_scram(Password),
|
||||
set_password_scram_t(
|
||||
LUser,
|
||||
LUser, LServer,
|
||||
Scram#scram.storedkey,
|
||||
Scram#scram.serverkey,
|
||||
Scram#scram.salt,
|
||||
@ -294,20 +304,27 @@ export(_Server) ->
|
||||
fun(Host, #passwd{us = {LUser, LServer}, password = Password})
|
||||
when LServer == Host,
|
||||
is_binary(Password) ->
|
||||
[?SQL("delete from users where username=%(LUser)s;"),
|
||||
?SQL("insert into users(username, password) "
|
||||
"values (%(LUser)s, %(Password)s);")];
|
||||
[?SQL("delete from users where username=%(LUser)s and %(LServer)H;"),
|
||||
?SQL_INSERT(
|
||||
"users",
|
||||
["username=%(LUser)s",
|
||||
"server_host=%(LServer)s",
|
||||
"password=%(Password)s"])];
|
||||
(Host, #passwd{us = {LUser, LServer}, password = #scram{} = Scram})
|
||||
when LServer == Host ->
|
||||
StoredKey = Scram#scram.storedkey,
|
||||
ServerKey = Scram#scram.serverkey,
|
||||
Salt = Scram#scram.salt,
|
||||
IterationCount = Scram#scram.iterationcount,
|
||||
[?SQL("delete from users where username=%(LUser)s;"),
|
||||
?SQL("insert into users(username, password, serverkey, salt, "
|
||||
"iterationcount) "
|
||||
"values (%(LUser)s, %(StoredKey)s, %(ServerKey)s,"
|
||||
" %(Salt)s, %(IterationCount)d);")];
|
||||
[?SQL("delete from users where username=%(LUser)s and %(LServer)H;"),
|
||||
?SQL_INSERT(
|
||||
"users",
|
||||
["username=%(LUser)s",
|
||||
"server_host=%(LServer)s",
|
||||
"password=%(StoredKey)s",
|
||||
"serverkey=%(ServerKey)s",
|
||||
"salt=%(Salt)s",
|
||||
"iterationcount=%(IterationCount)d"])];
|
||||
(_Host, _R) ->
|
||||
[]
|
||||
end}].
|
||||
|
@ -74,6 +74,7 @@ set_session(#session{sid = {Now, Pid}, usr = {U, LServer, R},
|
||||
"!pid=%(PidS)s",
|
||||
"node=%(Node)s",
|
||||
"username=%(U)s",
|
||||
"server_host=%(LServer)s",
|
||||
"resource=%(R)s",
|
||||
"priority=%(PrioS)s",
|
||||
"info=%(InfoS)s"]) of
|
||||
@ -107,7 +108,8 @@ get_sessions(LServer) ->
|
||||
case ejabberd_sql:sql_query(
|
||||
LServer,
|
||||
?SQL("select @(usec)d, @(pid)s, @(node)s, @(username)s,"
|
||||
" @(resource)s, @(priority)s, @(info)s from sm")) of
|
||||
" @(resource)s, @(priority)s, @(info)s from sm"
|
||||
" where %(LServer)H")) of
|
||||
{selected, Rows} ->
|
||||
lists:flatmap(
|
||||
fun(Row) ->
|
||||
@ -125,7 +127,7 @@ get_sessions(LUser, LServer) ->
|
||||
LServer,
|
||||
?SQL("select @(usec)d, @(pid)s, @(node)s, @(username)s,"
|
||||
" @(resource)s, @(priority)s, @(info)s from sm"
|
||||
" where username=%(LUser)s")) of
|
||||
" where username=%(LUser)s and %(LServer)H")) of
|
||||
{selected, Rows} ->
|
||||
{ok, lists:flatmap(
|
||||
fun(Row) ->
|
||||
|
@ -26,7 +26,7 @@
|
||||
-module(ejabberd_sql_pt).
|
||||
|
||||
%% API
|
||||
-export([parse_transform/2]).
|
||||
-export([parse_transform/2, format_error/1]).
|
||||
|
||||
-export([parse/2]).
|
||||
|
||||
@ -39,7 +39,8 @@
|
||||
args = [],
|
||||
res = [],
|
||||
res_vars = [],
|
||||
res_pos = 0}).
|
||||
res_pos = 0,
|
||||
server_host_used = false}).
|
||||
|
||||
-define(QUERY_RECORD, "sql_query").
|
||||
|
||||
@ -48,6 +49,12 @@
|
||||
|
||||
-define(MOD, sql__module_).
|
||||
|
||||
-ifdef(NEW_SQL_SCHEMA).
|
||||
-define(USE_NEW_SCHEMA, true).
|
||||
-else.
|
||||
-define(USE_NEW_SCHEMA, false).
|
||||
-endif.
|
||||
|
||||
%%====================================================================
|
||||
%% API
|
||||
%%====================================================================
|
||||
@ -57,11 +64,14 @@
|
||||
%%--------------------------------------------------------------------
|
||||
parse_transform(AST, _Options) ->
|
||||
%io:format("PT: ~p~nOpts: ~p~n", [AST, Options]),
|
||||
put(warnings, []),
|
||||
NewAST = top_transform(AST),
|
||||
%io:format("NewPT: ~p~n", [NewAST]),
|
||||
NewAST.
|
||||
NewAST ++ get(warnings).
|
||||
|
||||
|
||||
format_error(no_server_host) ->
|
||||
"server_host field is not used".
|
||||
|
||||
%%====================================================================
|
||||
%% Internal functions
|
||||
@ -80,6 +90,12 @@ transform(Form) ->
|
||||
S = erl_syntax:string_value(Arg),
|
||||
Pos = erl_syntax:get_pos(Arg),
|
||||
ParseRes = parse(S, Pos),
|
||||
if
|
||||
ParseRes#state.server_host_used ->
|
||||
ok;
|
||||
true ->
|
||||
add_warning(Pos, no_server_host)
|
||||
end,
|
||||
set_pos(make_sql_query(ParseRes), Pos);
|
||||
_ ->
|
||||
throw({error, erl_syntax:get_pos(Form),
|
||||
@ -101,8 +117,17 @@ transform(Form) ->
|
||||
parse_upsert(
|
||||
erl_syntax:list_elements(FieldsArg)),
|
||||
Pos = erl_syntax:get_pos(Form),
|
||||
case lists:keymember(
|
||||
"server_host", 1, ParseRes) of
|
||||
true ->
|
||||
ok;
|
||||
false ->
|
||||
add_warning(Pos, no_server_host)
|
||||
end,
|
||||
ParseRes2 =
|
||||
filter_upsert_sh(Table, ParseRes),
|
||||
set_pos(
|
||||
make_sql_upsert(Table, ParseRes, Pos),
|
||||
make_sql_upsert(Table, ParseRes2, Pos),
|
||||
Pos);
|
||||
_ ->
|
||||
throw({error, erl_syntax:get_pos(Form),
|
||||
@ -113,6 +138,38 @@ transform(Form) ->
|
||||
throw({error, erl_syntax:get_pos(Form),
|
||||
"wrong number of ?SQL_UPSERT args"})
|
||||
end;
|
||||
{?SQL_INSERT_MARK, 2} ->
|
||||
case erl_syntax:application_arguments(Form) of
|
||||
[TableArg, FieldsArg] ->
|
||||
case {erl_syntax:type(TableArg),
|
||||
erl_syntax:is_proper_list(FieldsArg)}of
|
||||
{string, true} ->
|
||||
Table = erl_syntax:string_value(TableArg),
|
||||
ParseRes =
|
||||
parse_insert(
|
||||
erl_syntax:list_elements(FieldsArg)),
|
||||
Pos = erl_syntax:get_pos(Form),
|
||||
case lists:keymember(
|
||||
"server_host", 1, ParseRes) of
|
||||
true ->
|
||||
ok;
|
||||
false ->
|
||||
add_warning(Pos, no_server_host)
|
||||
end,
|
||||
ParseRes2 =
|
||||
filter_upsert_sh(Table, ParseRes),
|
||||
set_pos(
|
||||
make_sql_insert(Table, ParseRes2),
|
||||
Pos);
|
||||
_ ->
|
||||
throw({error, erl_syntax:get_pos(Form),
|
||||
"?SQL_INSERT arguments must be "
|
||||
"a constant string and a list"})
|
||||
end;
|
||||
_ ->
|
||||
throw({error, erl_syntax:get_pos(Form),
|
||||
"wrong number of ?SQL_INSERT args"})
|
||||
end;
|
||||
_ ->
|
||||
Form
|
||||
end;
|
||||
@ -168,7 +225,7 @@ parse1([], Acc, State) ->
|
||||
};
|
||||
parse1([$@, $( | S], Acc, State) ->
|
||||
State1 = append_string(lists:reverse(Acc), State),
|
||||
{Name, Type, S1, State2} = parse_name(S, State1),
|
||||
{Name, Type, S1, State2} = parse_name(S, false, State1),
|
||||
Var = "__V" ++ integer_to_list(State2#state.res_pos),
|
||||
EVar = erl_syntax:variable(Var),
|
||||
Convert =
|
||||
@ -192,21 +249,43 @@ parse1([$@, $( | S], Acc, State) ->
|
||||
parse1(S1, [], State4);
|
||||
parse1([$%, $( | S], Acc, State) ->
|
||||
State1 = append_string(lists:reverse(Acc), State),
|
||||
{Name, Type, S1, State2} = parse_name(S, State1),
|
||||
{Name, Type, S1, State2} = parse_name(S, true, State1),
|
||||
Var = State2#state.param_pos,
|
||||
Convert =
|
||||
erl_syntax:application(
|
||||
erl_syntax:record_access(
|
||||
erl_syntax:variable(?ESCAPE_VAR),
|
||||
erl_syntax:atom(?ESCAPE_RECORD),
|
||||
erl_syntax:atom(Type)),
|
||||
[erl_syntax:variable(Name)]),
|
||||
State3 = State2,
|
||||
State4 =
|
||||
State3#state{'query' = [{var, Var} | State3#state.'query'],
|
||||
args = [Convert | State3#state.args],
|
||||
params = [Var | State3#state.params],
|
||||
param_pos = State3#state.param_pos + 1},
|
||||
case Type of
|
||||
host ->
|
||||
State3 = State2#state{server_host_used = true},
|
||||
case ?USE_NEW_SCHEMA of
|
||||
true ->
|
||||
Convert =
|
||||
erl_syntax:application(
|
||||
erl_syntax:record_access(
|
||||
erl_syntax:variable(?ESCAPE_VAR),
|
||||
erl_syntax:atom(?ESCAPE_RECORD),
|
||||
erl_syntax:atom(string)),
|
||||
[erl_syntax:variable(Name)]),
|
||||
State3#state{'query' = [{var, Var},
|
||||
{str, "server_host="} |
|
||||
State3#state.'query'],
|
||||
args = [Convert | State3#state.args],
|
||||
params = [Var | State3#state.params],
|
||||
param_pos = State3#state.param_pos + 1};
|
||||
false ->
|
||||
append_string("0=0", State3)
|
||||
end;
|
||||
_ ->
|
||||
Convert =
|
||||
erl_syntax:application(
|
||||
erl_syntax:record_access(
|
||||
erl_syntax:variable(?ESCAPE_VAR),
|
||||
erl_syntax:atom(?ESCAPE_RECORD),
|
||||
erl_syntax:atom(Type)),
|
||||
[erl_syntax:variable(Name)]),
|
||||
State2#state{'query' = [{var, Var} | State2#state.'query'],
|
||||
args = [Convert | State2#state.args],
|
||||
params = [Var | State2#state.params],
|
||||
param_pos = State2#state.param_pos + 1}
|
||||
end,
|
||||
parse1(S1, [], State4);
|
||||
parse1([C | S], Acc, State) ->
|
||||
parse1(S, [C | Acc], State).
|
||||
@ -216,32 +295,33 @@ append_string([], State) ->
|
||||
append_string(S, State) ->
|
||||
State#state{query = [{str, S} | State#state.query]}.
|
||||
|
||||
parse_name(S, State) ->
|
||||
parse_name(S, [], 0, State).
|
||||
parse_name(S, IsArg, State) ->
|
||||
parse_name(S, [], 0, IsArg, State).
|
||||
|
||||
parse_name([], _Acc, _Depth, State) ->
|
||||
parse_name([], _Acc, _Depth, _IsArg, State) ->
|
||||
throw({error, State#state.loc,
|
||||
"expected ')', found end of string"});
|
||||
parse_name([$), T | S], Acc, 0, State) ->
|
||||
parse_name([$), T | S], Acc, 0, IsArg, State) ->
|
||||
Type =
|
||||
case T of
|
||||
$d -> integer;
|
||||
$s -> string;
|
||||
$b -> boolean;
|
||||
$H when IsArg -> host;
|
||||
_ ->
|
||||
throw({error, State#state.loc,
|
||||
["unknown type specifier '", T, "'"]})
|
||||
end,
|
||||
{lists:reverse(Acc), Type, S, State};
|
||||
parse_name([$)], _Acc, 0, State) ->
|
||||
parse_name([$)], _Acc, 0, _IsArg, State) ->
|
||||
throw({error, State#state.loc,
|
||||
"expected type specifier, found end of string"});
|
||||
parse_name([$( = C | S], Acc, Depth, State) ->
|
||||
parse_name(S, [C | Acc], Depth + 1, State);
|
||||
parse_name([$) = C | S], Acc, Depth, State) ->
|
||||
parse_name(S, [C | Acc], Depth - 1, State);
|
||||
parse_name([C | S], Acc, Depth, State) ->
|
||||
parse_name(S, [C | Acc], Depth, State).
|
||||
parse_name([$( = C | S], Acc, Depth, IsArg, State) ->
|
||||
parse_name(S, [C | Acc], Depth + 1, IsArg, State);
|
||||
parse_name([$) = C | S], Acc, Depth, IsArg, State) ->
|
||||
parse_name(S, [C | Acc], Depth - 1, IsArg, State);
|
||||
parse_name([C | S], Acc, Depth, IsArg, State) ->
|
||||
parse_name(S, [C | Acc], Depth, IsArg, State).
|
||||
|
||||
|
||||
make_var(V) ->
|
||||
@ -444,7 +524,7 @@ make_sql_upsert_insert(Table, ParseRes) ->
|
||||
join_states(Fields, ", "),
|
||||
#state{'query' = [{str, ") VALUES ("}]},
|
||||
join_states(Vals, ", "),
|
||||
#state{'query' = [{str, ")"}]}
|
||||
#state{'query' = [{str, ");"}]}
|
||||
]),
|
||||
State.
|
||||
|
||||
@ -498,6 +578,49 @@ check_upsert(ParseRes, Pos) ->
|
||||
ok.
|
||||
|
||||
|
||||
parse_insert(Fields) ->
|
||||
{Fs, _} =
|
||||
lists:foldr(
|
||||
fun(F, {Acc, Param}) ->
|
||||
case erl_syntax:type(F) of
|
||||
string ->
|
||||
V = erl_syntax:string_value(F),
|
||||
{_, _, State} = Res =
|
||||
parse_insert_field(
|
||||
V, Param, erl_syntax:get_pos(F)),
|
||||
{[Res | Acc], State#state.param_pos};
|
||||
_ ->
|
||||
throw({error, erl_syntax:get_pos(F),
|
||||
"?SQL_INSERT field must be "
|
||||
"a constant string"})
|
||||
end
|
||||
end, {[], 0}, Fields),
|
||||
Fs.
|
||||
|
||||
parse_insert_field([$! | _S], _ParamPos, Loc) ->
|
||||
throw({error, Loc,
|
||||
"?SQL_INSERT fields must not start with \"!\""});
|
||||
parse_insert_field([$- | _S], _ParamPos, Loc) ->
|
||||
throw({error, Loc,
|
||||
"?SQL_INSERT fields must not start with \"-\""});
|
||||
parse_insert_field(S, ParamPos, Loc) ->
|
||||
{Name, ParseState} = parse_insert_field1(S, [], ParamPos, Loc),
|
||||
{Name, {true}, ParseState}.
|
||||
|
||||
parse_insert_field1([], _Acc, _ParamPos, Loc) ->
|
||||
throw({error, Loc,
|
||||
"?SQL_INSERT fields must have the "
|
||||
"following form: \"name=value\""});
|
||||
parse_insert_field1([$= | S], Acc, ParamPos, Loc) ->
|
||||
{lists:reverse(Acc), parse(S, ParamPos, Loc)};
|
||||
parse_insert_field1([C | S], Acc, ParamPos, Loc) ->
|
||||
parse_insert_field1(S, [C | Acc], ParamPos, Loc).
|
||||
|
||||
|
||||
make_sql_insert(Table, ParseRes) ->
|
||||
make_sql_query(make_sql_upsert_insert(Table, ParseRes)).
|
||||
|
||||
|
||||
concat_states(States) ->
|
||||
lists:foldr(
|
||||
fun(ST11, ST2) ->
|
||||
@ -566,3 +689,20 @@ set_pos(Tree, Pos) ->
|
||||
_ -> Node
|
||||
end
|
||||
end, Tree).
|
||||
|
||||
filter_upsert_sh(Table, ParseRes) ->
|
||||
case ?USE_NEW_SCHEMA of
|
||||
true ->
|
||||
ParseRes;
|
||||
false ->
|
||||
lists:filter(
|
||||
fun({Field, _Match, _ST}) ->
|
||||
Field /= "server_host" orelse Table == "route"
|
||||
end, ParseRes)
|
||||
end.
|
||||
|
||||
add_warning(Pos, Warning) ->
|
||||
Marker = erl_syntax:revert(
|
||||
erl_syntax:warning_marker({Pos, ?MODULE, Warning})),
|
||||
put(warnings, [Marker | get(warnings)]),
|
||||
ok.
|
||||
|
365
src/mod_admin_update_sql.erl
Normal file
365
src/mod_admin_update_sql.erl
Normal file
@ -0,0 +1,365 @@
|
||||
%%%-------------------------------------------------------------------
|
||||
%%% File : mod_admin_update_sql.erl
|
||||
%%% Author : Alexey Shchepin <alexey@process-one.net>
|
||||
%%% Purpose : Convert SQL DB to the new format
|
||||
%%% Created : 9 Aug 2017 by Alexey Shchepin <alexey@process-one.net>
|
||||
%%%
|
||||
%%%
|
||||
%%% ejabberd, Copyright (C) 2002-2017 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.
|
||||
%%%
|
||||
%%%-------------------------------------------------------------------
|
||||
|
||||
-module(mod_admin_update_sql).
|
||||
-author('alexey@process-one.net').
|
||||
|
||||
-behaviour(gen_mod).
|
||||
|
||||
-export([start/2, stop/1, reload/3, mod_opt_type/1,
|
||||
get_commands_spec/0, depends/2]).
|
||||
|
||||
% Commands API
|
||||
-export([update_sql/0]).
|
||||
|
||||
|
||||
-include("logger.hrl").
|
||||
-include("ejabberd.hrl").
|
||||
-include("ejabberd_commands.hrl").
|
||||
-include("xmpp.hrl").
|
||||
-include("ejabberd_sql_pt.hrl").
|
||||
|
||||
%%%
|
||||
%%% gen_mod
|
||||
%%%
|
||||
|
||||
start(_Host, _Opts) ->
|
||||
ejabberd_commands:register_commands(get_commands_spec()).
|
||||
|
||||
stop(_Host) ->
|
||||
ejabberd_commands:unregister_commands(get_commands_spec()).
|
||||
|
||||
reload(_Host, _NewOpts, _OldOpts) ->
|
||||
ok.
|
||||
|
||||
depends(_Host, _Opts) ->
|
||||
[].
|
||||
|
||||
%%%
|
||||
%%% Register commands
|
||||
%%%
|
||||
|
||||
get_commands_spec() ->
|
||||
[#ejabberd_commands{name = update_sql, tags = [sql],
|
||||
desc = "Convert SQL DB to the new format",
|
||||
module = ?MODULE, function = update_sql,
|
||||
args = [],
|
||||
args_example = [],
|
||||
args_desc = [],
|
||||
result = {res, rescode},
|
||||
result_example = ok,
|
||||
result_desc = "Status code: 0 on success, 1 otherwise"}
|
||||
].
|
||||
|
||||
update_sql() ->
|
||||
lists:foreach(
|
||||
fun(Host) ->
|
||||
case ejabberd_sql_sup:get_pids(Host) of
|
||||
[] ->
|
||||
ok;
|
||||
_ ->
|
||||
update_sql(Host)
|
||||
end
|
||||
end, ?MYHOSTS),
|
||||
ok.
|
||||
|
||||
-record(state, {host :: binary(),
|
||||
dbtype :: mysql | pgsql | sqlite | mssql | odbc,
|
||||
escape}).
|
||||
|
||||
update_sql(Host) ->
|
||||
LHost = jid:nameprep(Host),
|
||||
DBType = ejabberd_config:get_option({sql_type, LHost}, undefined),
|
||||
IsSupported =
|
||||
case DBType of
|
||||
pgsql -> true;
|
||||
_ -> false
|
||||
end,
|
||||
if
|
||||
not IsSupported ->
|
||||
io:format("Converting ~p DB is not supported~n", [DBType]),
|
||||
error;
|
||||
true ->
|
||||
Escape =
|
||||
case DBType of
|
||||
mssql -> fun ejabberd_sql:standard_escape/1;
|
||||
sqlite -> fun ejabberd_sql:standard_escape/1;
|
||||
_ -> fun ejabberd_sql:escape/1
|
||||
end,
|
||||
State = #state{host = LHost,
|
||||
dbtype = DBType,
|
||||
escape = Escape},
|
||||
update_tables(State)
|
||||
end.
|
||||
|
||||
update_tables(State) ->
|
||||
add_sh_column(State, "users"),
|
||||
drop_pkey(State, "users"),
|
||||
add_pkey(State, "users", ["server_host", "username"]),
|
||||
drop_sh_default(State, "users"),
|
||||
|
||||
add_sh_column(State, "last"),
|
||||
drop_pkey(State, "last"),
|
||||
add_pkey(State, "last", ["server_host", "username"]),
|
||||
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"),
|
||||
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"),
|
||||
|
||||
add_sh_column(State, "rostergroups"),
|
||||
drop_index(State, |