--- /dev/null
+--\r
+-- ejabberd, Copyright (C) 2002-2017 ProcessOne\r
+--\r
+-- This program is free software; you can redistribute it and/or\r
+-- modify it under the terms of the GNU General Public License as\r
+-- published by the Free Software Foundation; either version 2 of the\r
+-- License, or (at your option) any later version.\r
+--\r
+-- This program is distributed in the hope that it will be useful,\r
+-- but WITHOUT ANY WARRANTY; without even the implied warranty of\r
+-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU\r
+-- General Public License for more details.\r
+--\r
+-- You should have received a copy of the GNU General Public License along\r
+-- with this program; if not, write to the Free Software Foundation, Inc.,\r
+-- 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA.\r
+--\r
+\r
+SET ANSI_PADDING OFF;\r
+SET ANSI_NULLS ON;\r
+SET QUOTED_IDENTIFIER ON;\r
+SET ANSI_PADDING ON;\r
+\r
+CREATE TABLE [dbo].[archive] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [timestamp] [bigint] NOT NULL,\r
+ [peer] [varchar] (250) NOT NULL,\r
+ [bare_peer] [varchar] (250) NOT NULL,\r
+ [xml] [text] NOT NULL,\r
+ [txt] [text] NULL,\r
+ [id] [bigint] IDENTITY(1,1) NOT NULL,\r
+ [kind] [varchar] (10) NULL,\r
+ [nick] [varchar] (250) NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [archive_PK] PRIMARY KEY CLUSTERED \r
+(\r
+ [id] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [archive_username_timestamp] ON [archive] (username, timestamp)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [archive_username_peer] ON [archive] (username, peer)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [archive_username_bare_peer] ON [archive] (username, bare_peer)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [archive_timestamp] ON [archive] (timestamp)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[archive_prefs] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [def] [text] NOT NULL,\r
+ [always] [text] NOT NULL,\r
+ [never] [text] NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [archive_prefs_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[caps_features] (\r
+ [node] [varchar] (250) NOT NULL,\r
+ [subnode] [varchar] (250) NOT NULL,\r
+ [feature] [text] NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE CLUSTERED INDEX [caps_features_node_subnode] ON [caps_features] (node, subnode)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[last] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [seconds] [text] NOT NULL,\r
+ [state] [text] NOT NULL,\r
+ CONSTRAINT [last_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[motd] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [xml] [text] NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [motd_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[muc_registered] (\r
+ [jid] [varchar] (255) NOT NULL,\r
+ [host] [varchar] (255) NOT NULL,\r
+ [nick] [varchar] (255) NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+);\r
+\r
+CREATE INDEX [muc_registered_nick] ON [muc_registered] (nick)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [muc_registered_jid_host] ON [muc_registered] (jid, host)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[muc_room] (\r
+ [name] [varchar] (250) NOT NULL,\r
+ [host] [varchar] (250) NOT NULL,\r
+ [opts] [text] NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [muc_room_name_host] ON [muc_room] (name, host)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[muc_online_room] (\r
+ [name] [varchar] (250) NOT NULL,\r
+ [host] [varchar] (250) NOT NULL,\r
+ [node] [text] NOT NULL,\r
+ [pid] [text] NOT NULL\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [muc_online_room_name_host] ON [muc_online_room] (name, host)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[muc_online_users] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [server] [varchar] (250) NOT NULL,\r
+ [resource] [varchar] (250) NOT NULL,\r
+ [name] [varchar] (250) NOT NULL,\r
+ [host] [varchar] (250) NOT NULL,\r
+ node text NOT NULL\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [muc_online_users_i] ON [muc_online_users] (username, server, resource, name, host)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+CREATE UNIQUE CLUSTERED INDEX [muc_online_users_us] ON [muc_online_users] (username, server);\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[muc_room_subscribers] (\r
+ [room] [varchar] (191) NOT NULL,\r
+ [host] [varchar] (191) NOT NULL,\r
+ [jid] [varchar] (191) NOT NULL,\r
+ [nick] [text] NOT NULL,\r
+ [nodes] [text] NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [muc_room_subscribers_host_room_jid] ON [muc_room_subscribers] (host, room, jid);\r
+CREATE INDEX [muc_room_subscribers_host_jid] ON [muc_room_subscribers] (host, jid);\r
+\r
+CREATE TABLE [dbo].[privacy_default_list] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [name] [varchar] (250) NOT NULL,\r
+ CONSTRAINT [privacy_default_list_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+);\r
+\r
+CREATE TABLE [dbo].[privacy_list] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [name] [varchar] (250) NOT NULL,\r
+ [id] [bigint] IDENTITY(1,1) NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [privacy_list_PK] PRIMARY KEY CLUSTERED \r
+(\r
+ [id] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+);\r
+\r
+CREATE INDEX [privacy_list_username] ON [privacy_list] (username)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE INDEX [privacy_list_username_name] ON [privacy_list] (username, name)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[privacy_list_data] (\r
+ [id] [bigint] NULL,\r
+ [t] [char] (1) NOT NULL,\r
+ [value] [text] NOT NULL,\r
+ [action] [char] (1) NOT NULL,\r
+ [ord] [smallint] NOT NULL,\r
+ [match_all] [smallint] NOT NULL,\r
+ [match_iq] [smallint] NOT NULL,\r
+ [match_message] [smallint] NOT NULL,\r
+ [match_presence_in] [smallint] NOT NULL,\r
+ [match_presence_out] [smallint] NOT NULL\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE CLUSTERED INDEX [privacy_list_data_id] ON [privacy_list_data] (id)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[private_storage] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [namespace] [varchar] (250) NOT NULL,\r
+ [data] [text] NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [private_storage_username] ON [private_storage] (username)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [private_storage_username_namespace] ON [private_storage] (username, namespace)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[pubsub_item] (\r
+ [nodeid] [bigint] NULL,\r
+ [itemid] [varchar] (255) NOT NULL,\r
+ [publisher] [text] NOT NULL,\r
+ [creation] [varchar] (32) NOT NULL,\r
+ [modification] [varchar] (32) NOT NULL,\r
+ [payload] [text] NOT NULL DEFAULT ''\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [pubsub_item_itemid] ON [pubsub_item] (itemid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [pubsub_item_nodeid_itemid] ON [pubsub_item] (nodeid, itemid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[pubsub_node_option] (\r
+ [nodeid] [bigint] NULL,\r
+ [name] [text] NOT NULL,\r
+ [val] [text] NOT NULL\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE CLUSTERED INDEX [pubsub_node_option_nodeid] ON [pubsub_node_option] (nodeid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[pubsub_node_owner] (\r
+ [nodeid] [bigint] NULL,\r
+ [owner] [text] NOT NULL\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE CLUSTERED INDEX [pubsub_node_owner_nodeid] ON [pubsub_node_owner] (nodeid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[pubsub_state] (\r
+ [nodeid] [bigint] NULL,\r
+ [jid] [varchar] (255) NOT NULL,\r
+ [affiliation] [char] (1) NOT NULL,\r
+ [subscriptions] [text] NOT NULL DEFAULT '',\r
+ [stateid] [bigint] IDENTITY(1,1) NOT NULL,\r
+ CONSTRAINT [pubsub_state_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [stateid] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [pubsub_state_jid] ON [pubsub_state] (jid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE INDEX [pubsub_state_nodeid_jid] ON [pubsub_state] (nodeid, jid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[pubsub_subscription_opt] (\r
+ [subid] [varchar] (255) NOT NULL,\r
+ [opt_name] [varchar] (32) NOT NULL,\r
+ [opt_value] [text] NOT NULL\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [pubsub_subscription_opt_subid_opt_name] ON [pubsub_subscription_opt] (subid, opt_name)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[pubsub_node] (\r
+ [host] [varchar] (255) NOT NULL,\r
+ [node] [varchar] (255) NOT NULL,\r
+ [parent] [varchar] (255) NOT NULL DEFAULT '',\r
+ [plugin] [text] NOT NULL,\r
+ [nodeid] [bigint] IDENTITY(1,1) NOT NULL,\r
+ CONSTRAINT [pubsub_node_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [nodeid] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [pubsub_node_parent] ON [pubsub_node] (parent)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE INDEX [pubsub_node_host_node] ON [pubsub_node] (host, node)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[roster_version] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [version] [text] NOT NULL,\r
+ CONSTRAINT [roster_version_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[rostergroups] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [jid] [varchar] (250) NOT NULL,\r
+ [grp] [text] NOT NULL\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE CLUSTERED INDEX [rostergroups_username_jid] ON [rostergroups] ([username], [jid])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[rosterusers] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [jid] [varchar] (250) NOT NULL,\r
+ [nick] [text] NOT NULL,\r
+ [subscription] [char] (1) NOT NULL,\r
+ [ask] [char] (1) NOT NULL,\r
+ [askmessage] [text] NOT NULL,\r
+ [server] [char] (1) NOT NULL,\r
+ [subscribe] [text] NOT NULL,\r
+ [type] [text] NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [rosterusers_username_jid] ON [rosterusers] ([username], [jid])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [rosterusers_username] ON [rosterusers] ([username])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [rosterusers_jid] ON [rosterusers] ([jid])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[sm] (\r
+ [usec] [bigint] NOT NULL,\r
+ [pid] [varchar] (100) NOT NULL,\r
+ [node] [varchar] (255) NOT NULL,\r
+ [username] [varchar] (255) NOT NULL,\r
+ [resource] [varchar] (255) NOT NULL,\r
+ [priority] [text] NOT NULL,\r
+ [info] [text] NOT NULL\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [sm_sid] ON [sm] (usec, pid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [sm_node] ON [sm] (node)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [sm_username] ON [sm] (username)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[spool] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [xml] [text] NOT NULL,\r
+ [seq] [bigint] IDENTITY(1,1) NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [spool_PK] PRIMARY KEY CLUSTERED \r
+(\r
+ [seq] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [spool_username] ON [spool] (username)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [spool_created_at] ON [spool] (created_at)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+;\r
+\r
+CREATE TABLE [dbo].[sr_group] (\r
+ [name] [varchar] (250) NOT NULL,\r
+ [opts] [text] NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [sr_group_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [name] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[sr_user] (\r
+ [jid] [varchar] (250) NOT NULL,\r
+ [grp] [varchar] (250) NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE()\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [sr_user_jid_group] ON [sr_user] ([jid], [grp])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [sr_user_jid] ON [sr_user] ([jid])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [sr_user_grp] ON [sr_user] ([grp])\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[users] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [password] [text] NOT NULL,\r
+ [serverkey] [text] NOT NULL DEFAULT '',\r
+ [salt] [text] NOT NULL DEFAULT '',\r
+ [iterationcount] [smallint] NOT NULL DEFAULT 0,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [users_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[vcard] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [vcard] [text] NOT NULL,\r
+ [created_at] [datetime] NOT NULL DEFAULT GETDATE(),\r
+ CONSTRAINT [vcard_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [username] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[vcard_search] (\r
+ [username] [varchar] (250) NOT NULL,\r
+ [lusername] [varchar] (250) NOT NULL,\r
+ [fn] [text] NOT NULL,\r
+ [lfn] [varchar] (250) NOT NULL,\r
+ [family] [text] NOT NULL,\r
+ [lfamily] [varchar] (250) NOT NULL,\r
+ [given] [text] NOT NULL,\r
+ [lgiven] [varchar] (250) NOT NULL,\r
+ [middle] [text] NOT NULL,\r
+ [lmiddle] [varchar] (250) NOT NULL,\r
+ [nickname] [text] NOT NULL,\r
+ [lnickname] [varchar] (250) NOT NULL,\r
+ [bday] [text] NOT NULL,\r
+ [lbday] [varchar] (250) NOT NULL,\r
+ [ctry] [text] NOT NULL,\r
+ [lctry] [varchar] (250) NOT NULL,\r
+ [locality] [text] NOT NULL,\r
+ [llocality] [varchar] (250) NOT NULL,\r
+ [email] [text] NOT NULL,\r
+ [lemail] [varchar] (250) NOT NULL,\r
+ [orgname] [text] NOT NULL,\r
+ [lorgname] [varchar] (250) NOT NULL,\r
+ [orgunit] [text] NOT NULL,\r
+ [lorgunit] [varchar] (250) NOT NULL,\r
+ CONSTRAINT [vcard_search_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [lusername] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE INDEX [vcard_search_lfn] ON [vcard_search] (lfn)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lfamily] ON [vcard_search] (lfamily)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lgiven] ON [vcard_search] (lgiven)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lmiddle] ON [vcard_search] (lmiddle)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lnickname] ON [vcard_search] (lnickname)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lbday] ON [vcard_search] (lbday)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lctry] ON [vcard_search] (lctry)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_llocality] ON [vcard_search] (llocality)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lemail] ON [vcard_search] (lemail)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lorgname] ON [vcard_search] (lorgname)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [vcard_search_lorgunit] ON [vcard_search] (lorgunit)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+ALTER TABLE [dbo].[pubsub_item] WITH CHECK ADD CONSTRAINT [pubsub_item_ibfk_1] FOREIGN KEY([nodeid])\r
+REFERENCES [dbo].[pubsub_node] ([nodeid])\r
+ON DELETE CASCADE;\r
+\r
+ALTER TABLE [dbo].[pubsub_item] CHECK CONSTRAINT [pubsub_item_ibfk_1];\r
+\r
+ALTER TABLE [dbo].[pubsub_node_option] WITH CHECK ADD CONSTRAINT [pubsub_node_option_ibfk_1] FOREIGN KEY([nodeid])\r
+REFERENCES [dbo].[pubsub_node] ([nodeid])\r
+ON DELETE CASCADE;\r
+\r
+ALTER TABLE [dbo].[pubsub_node_option] CHECK CONSTRAINT [pubsub_node_option_ibfk_1];\r
+\r
+ALTER TABLE [dbo].[pubsub_node_owner] WITH CHECK ADD CONSTRAINT [pubsub_node_owner_ibfk_1] FOREIGN KEY([nodeid])\r
+REFERENCES [dbo].[pubsub_node] ([nodeid])\r
+ON DELETE CASCADE;\r
+\r
+ALTER TABLE [dbo].[pubsub_node_owner] CHECK CONSTRAINT [pubsub_node_owner_ibfk_1];\r
+\r
+ALTER TABLE [dbo].[pubsub_state] WITH CHECK ADD CONSTRAINT [pubsub_state_ibfk_1] FOREIGN KEY([nodeid])\r
+REFERENCES [dbo].[pubsub_node] ([nodeid])\r
+ON DELETE CASCADE;\r
+\r
+ALTER TABLE [dbo].[pubsub_state] CHECK CONSTRAINT [pubsub_state_ibfk_1];\r
+\r
+CREATE TABLE [dbo].[oauth_token] (\r
+ [token] [varchar] (250) NOT NULL,\r
+ [jid] [text] NOT NULL,\r
+ [scope] [text] NOT NULL,\r
+ [expire] [bigint] NOT NULL,\r
+ CONSTRAINT [oauth_token_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [token] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[route] (\r
+ [domain] [varchar] (255) NOT NULL,\r
+ [server_host] [varchar] (255) NOT NULL,\r
+ [node] [varchar] (255) NOT NULL,\r
+ [pid] [varchar](100) NOT NULL,\r
+ [local_hint] [text] NOT NULL\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [route_i] ON [route] (domain, server_host, node, pid)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [route_domain] ON [route] (domain)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[bosh] (\r
+ [sid] [varchar] (255) NOT NULL,\r
+ [node] [varchar] (255) NOT NULL,\r
+ [pid] [varchar](100) NOT NULL\r
+ CONSTRAINT [bosh_PRIMARY] PRIMARY KEY CLUSTERED \r
+(\r
+ [sid] ASC\r
+)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)\r
+) TEXTIMAGE_ON [PRIMARY];\r
+\r
+CREATE TABLE [dbo].[carboncopy] (\r
+ [username] [varchar] (255) NOT NULL,\r
+ [resource] [varchar] (255) NOT NULL,\r
+ [namespace] [varchar] (255) NOT NULL,\r
+ [node] [varchar] (255) NOT NULL\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [carboncopy_ur] ON [carboncopy] (username, resource)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE INDEX [carboncopy_user] ON [carboncopy] (username)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE TABLE [dbo].[push_session] (\r
+ [username] [varchar] (255) NOT NULL,\r
+ [timestamp] [bigint] NOT NULL,\r
+ [service] [varchar] (255) NOT NULL,\r
+ [node] [varchar] (255) NOT NULL,\r
+ [xml] [varchar] (255) NOT NULL\r
+);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [i_push_usn] ON [push_session] (username, service, node)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
+\r
+CREATE UNIQUE CLUSTERED INDEX [i_push_ut] ON [push_session] (username, timestamp)\r
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON);\r
--- /dev/null
+CREATE TABLE `users` (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ password text NOT NULL,
+ serverkey varchar(64) NOT NULL DEFAULT '',
+ salt varchar(64) NOT NULL DEFAULT '',
+ iterationcount integer NOT NULL DEFAULT 0,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
--- /dev/null
+CREATE TABLE oauth_token (
+ token varchar(191) NOT NULL PRIMARY KEY,
+ jid text NOT NULL,
+ scope text NOT NULL,
+ `expire` bigint NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
--- /dev/null
+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
+) 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));
--- /dev/null
+CREATE TABLE sm (
+ usec bigint NOT NULL,
+ pid text NOT NULL,
+ node text NOT NULL,
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ resource varchar(191) NOT NULL,
+ priority text NOT NULL,
+ info text NOT NULL,
+ PRIMARY KEY (usec, pid(75))
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_sm_node ON sm(node(75));
+CREATE INDEX i_sm_sh_username ON sm(server_host(191), username);
--- /dev/null
+CREATE TABLE motd (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ xml text,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
--- /dev/null
+CREATE TABLE bosh (
+ sid text NOT NULL,
+ node text NOT NULL,
+ pid text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_bosh_sid ON bosh(sid(75));
--- /dev/null
+CREATE TABLE caps_features (
+ node varchar(191) NOT NULL,
+ subnode varchar(191) NOT NULL,
+ feature text,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_caps_features_node_subnode ON caps_features(node(75), subnode(75));
--- /dev/null
+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(191), username(191), resource(191))
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_carboncopy_sh_user ON carboncopy (server_host(191), username(75));
--- /dev/null
+CREATE TABLE last (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ seconds text NOT NULL,
+ state text NOT NULL,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
--- /dev/null
+CREATE TABLE archive (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ timestamp BIGINT UNSIGNED NOT NULL,
+ peer varchar(191) NOT NULL,
+ bare_peer varchar(191) NOT NULL,
+ xml text NOT NULL,
+ txt text,
+ id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE,
+ kind varchar(10),
+ nick varchar(191),
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_archive_sh_username_timestamp ON archive(server_host(191), username(191), timestamp);
+CREATE INDEX i_archive_sh_username_peer ON archive(server_host(191), username(191), peer(191));
+CREATE INDEX i_archive_sh_username_bare_peer ON archive(server_host(191), username(191), bare_peer(191));
+CREATE INDEX i_archive_sh_timestamp ON archive(server_host(191), timestamp);
+
+CREATE TABLE archive_prefs (
+ username varchar(191) 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 CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
--- /dev/null
+CREATE TABLE muc_room (
+ name text NOT NULL,
+ host text NOT NULL,
+ server_host text NOT NULL,
+ opts mediumtext NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_muc_room_name_host ON muc_room(name(75), host(75));
+
+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 CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_muc_registered_nick ON muc_registered(nick(75));
+CREATE UNIQUE INDEX i_muc_registered_jid_host ON muc_registered(jid(75), host(75));
+
+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
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_muc_online_room_name_host ON muc_online_room(name(75), host(75));
+
+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
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_muc_online_users ON muc_online_users(username(75), server(75), resource(75), name(75), host(75));
+CREATE INDEX i_muc_online_users_us ON muc_online_users(username(75), server(75));
+
+CREATE TABLE 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 timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_muc_room_subscribers_host_room_jid ON muc_room_subscribers(host, room, jid);
+CREATE INDEX i_muc_room_subscribers_host_jid ON muc_room_subscribers(host, jid);
--- /dev/null
+CREATE TABLE spool (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ xml BLOB NOT NULL,
+ seq BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_spool_sh_username ON spool(server_host(191), username);
+CREATE INDEX i_spool_created_at ON spool(created_at);
--- /dev/null
+CREATE TABLE privacy_default_list (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ name varchar(191) NOT NULL,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE privacy_list (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ name varchar(191) NOT NULL,
+ id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_privacy_list_sh_username ON privacy_list(server_host(191), username);
+CREATE UNIQUE INDEX i_privacy_list_sh_username_name ON privacy_list (server_host(191), username(75), name(75));
+
+CREATE TABLE privacy_list_data (
+ id bigint,
+ 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
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_privacy_list_data_id ON privacy_list_data(id);
--- /dev/null
+CREATE TABLE private_storage (
+ username varchar(191) NOT NULL,
+ server_host text 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)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_private_storage_sh_username ON private_storage(server_host(191), username);
--- /dev/null
+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
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_proxy65_sid ON proxy65 (sid(191));
+CREATE INDEX i_proxy65_jid ON proxy65 (jid_i(191));
--- /dev/null
+CREATE TABLE pubsub_node (
+ host text NOT NULL,
+ node text NOT NULL,
+ parent VARCHAR(191) NOT NULL DEFAULT '',
+ plugin text NOT NULL,
+ nodeid bigint auto_increment primary key
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_node_parent ON pubsub_node(parent(120));
+CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node(host(20), node(120));
+
+CREATE TABLE pubsub_node_option (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ name text NOT NULL,
+ val text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_node_option_nodeid ON pubsub_node_option(nodeid);
+
+CREATE TABLE pubsub_node_owner (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ owner text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_node_owner_nodeid ON pubsub_node_owner(nodeid);
+
+CREATE TABLE pubsub_state (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ jid text NOT NULL,
+ affiliation character(1),
+ subscriptions VARCHAR(191) NOT NULL DEFAULT '',
+ stateid bigint auto_increment primary key
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_state_jid ON pubsub_state(jid(60));
+CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state(nodeid, jid(60));
+
+CREATE TABLE pubsub_item (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ itemid text NOT NULL,
+ publisher text NOT NULL,
+ creation varchar(32) NOT NULL,
+ modification varchar(32) NOT NULL,
+ payload text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_item_itemid ON pubsub_item(itemid(36));
+CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item(nodeid, itemid(36));
+
+CREATE TABLE pubsub_subscription_opt (
+ subid text NOT NULL,
+ opt_name varchar(32),
+ opt_value text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE UNIQUE INDEX i_pubsub_subscription_opt ON pubsub_subscription_opt(subid(32), opt_name(32));
--- /dev/null
+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(191), username(191), timestamp)
+);
+
+CREATE UNIQUE INDEX i_push_session_susn ON push_session (server_host(191), username(191), service(191), node(191));
--- /dev/null
+CREATE TABLE rosterusers (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ jid varchar(191) 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 CURRENT_TIMESTAMP
+) 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 (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ jid varchar(191) NOT NULL,
+ grp text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_rosterg_sh_user_jid ON rostergroups(server_host(191), username(75), jid(75));
+
+CREATE TABLE roster_version (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ version text NOT NULL,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
--- /dev/null
+CREATE TABLE sr_group (
+ name varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ opts text NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host(191), name)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE sr_user (
+ jid varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ grp varchar(191) NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host(191), jid, grp)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+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);
--- /dev/null
+CREATE TABLE vcard (
+ username varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ vcard mediumtext NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host(191), username)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE vcard_search (
+ username varchar(191) NOT NULL,
+ lusername varchar(191) NOT NULL,
+ server_host text NOT NULL,
+ fn text NOT NULL,
+ lfn varchar(191) NOT NULL,
+ family text NOT NULL,
+ lfamily varchar(191) NOT NULL,
+ given text NOT NULL,
+ lgiven varchar(191) NOT NULL,
+ middle text NOT NULL,
+ lmiddle varchar(191) NOT NULL,
+ nickname text NOT NULL,
+ lnickname varchar(191) NOT NULL,
+ bday text NOT NULL,
+ lbday varchar(191) NOT NULL,
+ ctry text NOT NULL,
+ lctry varchar(191) NOT NULL,
+ locality text NOT NULL,
+ llocality varchar(191) NOT NULL,
+ email text NOT NULL,
+ lemail varchar(191) NOT NULL,
+ orgname text NOT NULL,
+ lorgname varchar(191) NOT NULL,
+ orgunit text NOT NULL,
+ lorgunit varchar(191) NOT NULL,
+ PRIMARY KEY (server_host(191), lusername)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_vcard_search_sh_lfn ON vcard_search(server_host(191), lfn);
+CREATE INDEX i_vcard_search_sh_lfamily ON vcard_search(server_host(191), lfamily);
+CREATE INDEX i_vcard_search_sh_lgiven ON vcard_search(server_host(191), lgiven);
+CREATE INDEX i_vcard_search_sh_lmiddle ON vcard_search(server_host(191), lmiddle);
+CREATE INDEX i_vcard_search_sh_lnickname ON vcard_search(server_host(191), lnickname);
+CREATE INDEX i_vcard_search_sh_lbday ON vcard_search(server_host(191), lbday);
+CREATE INDEX i_vcard_search_sh_lctry ON vcard_search(server_host(191), lctry);
+CREATE INDEX i_vcard_search_sh_llocality ON vcard_search(server_host(191), llocality);
+CREATE INDEX i_vcard_search_sh_lemail ON vcard_search(server_host(191), lemail);
+CREATE INDEX i_vcard_search_sh_lorgname ON vcard_search(server_host(191), lorgname);
+CREATE INDEX i_vcard_search_sh_lorgunit ON vcard_search(server_host(191), lorgunit);
--- /dev/null
+--
+-- 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.
+--
+
+CREATE TABLE users (
+ username varchar(191) PRIMARY KEY,
+ password text NOT NULL,
+ serverkey varchar(64) NOT NULL DEFAULT '',
+ salt varchar(64) NOT NULL DEFAULT '',
+ iterationcount integer NOT NULL DEFAULT 0,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+-- Add support for SCRAM auth to a database created before ejabberd 16.03:
+-- ALTER TABLE users ADD COLUMN serverkey varchar(64) NOT NULL DEFAULT '';
+-- ALTER TABLE users ADD COLUMN salt varchar(64) NOT NULL DEFAULT '';
+-- ALTER TABLE users ADD COLUMN iterationcount integer NOT NULL DEFAULT 0;
+
+CREATE TABLE last (
+ username varchar(191) PRIMARY KEY,
+ seconds text NOT NULL,
+ state text NOT NULl
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+
+CREATE TABLE rosterusers (
+ username varchar(191) NOT NULL,
+ jid varchar(191) 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 CURRENT_TIMESTAMP
+) 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 (
+ username varchar(191) NOT NULL,
+ jid varchar(191) NOT NULL,
+ grp text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX pk_rosterg_user_jid ON rostergroups(username(75), jid(75));
+
+CREATE TABLE sr_group (
+ name varchar(191) NOT NULL,
+ opts text NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE sr_user (
+ jid varchar(191) NOT NULL,
+ grp varchar(191) NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) 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 (
+ username varchar(191) NOT NULL,
+ xml BLOB NOT NULL,
+ seq BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_despool USING BTREE ON spool(username);
+CREATE INDEX i_spool_created_at USING BTREE ON spool(created_at);
+
+CREATE TABLE archive (
+ username varchar(191) NOT NULL,
+ timestamp BIGINT UNSIGNED NOT NULL,
+ peer varchar(191) NOT NULL,
+ bare_peer varchar(191) NOT NULL,
+ xml text NOT NULL,
+ txt text,
+ id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE,
+ kind varchar(10),
+ nick varchar(191),
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE FULLTEXT INDEX i_text ON archive(txt);
+CREATE INDEX i_username_timestamp USING BTREE ON archive(username(191), timestamp);
+CREATE INDEX i_username_peer USING BTREE ON archive(username(191), peer(191));
+CREATE INDEX i_username_bare_peer USING BTREE ON archive(username(191), bare_peer(191));
+CREATE INDEX i_timestamp USING BTREE ON archive(timestamp);
+
+CREATE TABLE archive_prefs (
+ username varchar(191) NOT NULL PRIMARY KEY,
+ def text NOT NULL,
+ always text NOT NULL,
+ never text NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE vcard (
+ username varchar(191) PRIMARY KEY,
+ vcard mediumtext NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE vcard_search (
+ username varchar(191) NOT NULL,
+ lusername varchar(191) PRIMARY KEY,
+ fn text NOT NULL,
+ lfn varchar(191) NOT NULL,
+ family text NOT NULL,
+ lfamily varchar(191) NOT NULL,
+ given text NOT NULL,
+ lgiven varchar(191) NOT NULL,
+ middle text NOT NULL,
+ lmiddle varchar(191) NOT NULL,
+ nickname text NOT NULL,
+ lnickname varchar(191) NOT NULL,
+ bday text NOT NULL,
+ lbday varchar(191) NOT NULL,
+ ctry text NOT NULL,
+ lctry varchar(191) NOT NULL,
+ locality text NOT NULL,
+ llocality varchar(191) NOT NULL,
+ email text NOT NULL,
+ lemail varchar(191) NOT NULL,
+ orgname text NOT NULL,
+ lorgname varchar(191) NOT NULL,
+ orgunit text NOT NULL,
+ lorgunit varchar(191) NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_vcard_search_lfn ON vcard_search(lfn);
+CREATE INDEX i_vcard_search_lfamily ON vcard_search(lfamily);
+CREATE INDEX i_vcard_search_lgiven ON vcard_search(lgiven);
+CREATE INDEX i_vcard_search_lmiddle ON vcard_search(lmiddle);
+CREATE INDEX i_vcard_search_lnickname ON vcard_search(lnickname);
+CREATE INDEX i_vcard_search_lbday ON vcard_search(lbday);
+CREATE INDEX i_vcard_search_lctry ON vcard_search(lctry);
+CREATE INDEX i_vcard_search_llocality ON vcard_search(llocality);
+CREATE INDEX i_vcard_search_lemail ON vcard_search(lemail);
+CREATE INDEX i_vcard_search_lorgname ON vcard_search(lorgname);
+CREATE INDEX i_vcard_search_lorgunit ON vcard_search(lorgunit);
+
+CREATE TABLE privacy_default_list (
+ username varchar(191) PRIMARY KEY,
+ name varchar(191) NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE privacy_list (
+ username varchar(191) NOT NULL,
+ name varchar(191) NOT NULL,
+ id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE,
+ 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 (
+ id bigint,
+ 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
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_privacy_list_data_id ON privacy_list_data(id);
+
+CREATE TABLE private_storage (
+ username varchar(191) NOT NULL,
+ namespace varchar(191) NOT NULL,
+ data text NOT NULL,
+ 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
+CREATE TABLE roster_version (
+ username varchar(191) PRIMARY KEY,
+ version text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+-- To update from 1.x:
+-- ALTER TABLE rosterusers ADD COLUMN askmessage text AFTER ask;
+-- 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 VARCHAR(191) NOT NULL DEFAULT '',
+ plugin text NOT NULL,
+ nodeid bigint auto_increment primary key
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_node_parent ON pubsub_node(parent(120));
+CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node(host(20), node(120));
+
+CREATE TABLE pubsub_node_option (
+ nodeid bigint,
+ name text NOT NULL,
+ val text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_node_option_nodeid ON pubsub_node_option(nodeid);
+ALTER TABLE `pubsub_node_option` ADD FOREIGN KEY (`nodeid`) REFERENCES `pubsub_node` (`nodeid`) ON DELETE CASCADE;
+
+CREATE TABLE pubsub_node_owner (
+ nodeid bigint,
+ owner text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_node_owner_nodeid ON pubsub_node_owner(nodeid);
+ALTER TABLE `pubsub_node_owner` ADD FOREIGN KEY (`nodeid`) REFERENCES `pubsub_node` (`nodeid`) ON DELETE CASCADE;
+
+CREATE TABLE pubsub_state (
+ nodeid bigint,
+ jid text NOT NULL,
+ affiliation character(1),
+ subscriptions VARCHAR(191) NOT NULL DEFAULT '',
+ stateid bigint auto_increment primary key
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_state_jid ON pubsub_state(jid(60));
+CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state(nodeid, jid(60));
+ALTER TABLE `pubsub_state` ADD FOREIGN KEY (`nodeid`) REFERENCES `pubsub_node` (`nodeid`) ON DELETE CASCADE;
+
+CREATE TABLE pubsub_item (
+ nodeid bigint,
+ itemid text NOT NULL,
+ publisher text NOT NULL,
+ creation varchar(32) NOT NULL,
+ modification varchar(32) NOT NULL,
+ payload text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE INDEX i_pubsub_item_itemid ON pubsub_item(itemid(36));
+CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item(nodeid, itemid(36));
+ALTER TABLE `pubsub_item` ADD FOREIGN KEY (`nodeid`) REFERENCES `pubsub_node` (`nodeid`) ON DELETE CASCADE;
+
+CREATE TABLE pubsub_subscription_opt (
+ subid text NOT NULL,
+ opt_name varchar(32),
+ opt_value text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+CREATE UNIQUE INDEX i_pubsub_subscription_opt ON pubsub_subscription_opt(subid(32), opt_name(32));
+
+CREATE TABLE muc_room (
+ name text NOT NULL,
+ host text NOT NULL,
+ opts mediumtext NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_muc_room_name_host USING BTREE ON muc_room(name(75), host(75));
+
+CREATE TABLE muc_registered (
+ jid text NOT NULL,
+ host text NOT NULL,
+ nick text NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_muc_registered_nick USING BTREE ON muc_registered(nick(75));
+CREATE UNIQUE INDEX i_muc_registered_jid_host USING BTREE ON muc_registered(jid(75), host(75));
+
+CREATE TABLE muc_online_room (
+ name text NOT NULL,
+ host text NOT NULL,
+ node text NOT NULL,
+ pid text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_muc_online_room_name_host USING BTREE ON muc_online_room(name(75), host(75));
+
+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,
+ node text NOT NULL
+) 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,
+ host varchar(191) NOT NULL,
+ jid varchar(191) NOT NULL,
+ nick text NOT NULL,
+ nodes text NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ UNIQUE KEY i_muc_room_subscribers_host_room_jid (host, room, jid)
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_muc_room_subscribers_host_jid USING BTREE ON muc_room_subscribers(host, jid);
+
+CREATE TABLE motd (
+ username varchar(191) PRIMARY KEY,
+ xml text,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE caps_features (
+ node varchar(191) NOT NULL,
+ subnode varchar(191) NOT NULL,
+ feature text,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE INDEX i_caps_features_node_subnode ON caps_features(node(75), subnode(75));
+
+CREATE TABLE sm (
+ usec bigint NOT NULL,
+ pid text NOT NULL,
+ node text NOT NULL,
+ username varchar(191) NOT NULL,
+ resource varchar(191) NOT NULL,
+ priority text NOT NULL,
+ info text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_sid ON sm(usec, pid(75));
+CREATE INDEX i_node ON sm(node(75));
+CREATE INDEX i_username ON sm(username);
+
+CREATE TABLE oauth_token (
+ token varchar(191) NOT NULL PRIMARY KEY,
+ jid text NOT NULL,
+ scope text NOT NULL,
+ expire bigint NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+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
+) 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,
+ node text NOT NULL,
+ pid text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_bosh_sid ON bosh(sid(75));
+
+CREATE TABLE carboncopy (
+ username text NOT NULL,
+ resource text NOT NULL,
+ namespace text NOT NULL,
+ node text NOT NULL
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_carboncopy_ur ON carboncopy (username(75), resource(75));
+CREATE INDEX i_carboncopy_user ON carboncopy (username(75));
+
+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
+) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE UNIQUE INDEX i_proxy65_sid ON proxy65 (sid(191));
+CREATE INDEX i_proxy65_jid ON proxy65 (jid_i(191));
+
+CREATE TABLE push_session (
+ username text NOT NULL,
+ timestamp bigint NOT NULL,
+ service text NOT NULL,
+ node text NOT NULL,
+ xml text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_push_usn ON push_session (username(191), service(191), node(191));
+CREATE UNIQUE INDEX i_push_ut ON push_session (username(191), timestamp);
--- /dev/null
+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 CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host, username)
+);
--- /dev/null
+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 (token);
--- /dev/null
+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 (domain, server_host, node, pid);
+CREATE INDEX i_route_domain ON route (domain);
--- /dev/null
+CREATE TABLE sm (
+ usec bigint NOT NULL,
+ pid text NOT NULL,
+ node text NOT NULL,
+ username text NOT NULL,
+ server_host 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 (node);
+CREATE INDEX i_sm_sh_username ON sm (server_host, username);
--- /dev/null
+CREATE TABLE motd (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ xml text,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host, username)
+);
--- /dev/null
+CREATE TABLE bosh (
+ sid text NOT NULL,
+ node text NOT NULL,
+ pid text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_bosh_sid ON bosh (sid);
--- /dev/null
+CREATE TABLE caps_features (
+ node text NOT NULL,
+ subnode text NOT NULL,
+ feature text,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_caps_features_node_subnode ON caps_features (node, subnode);
--- /dev/null
+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 (server_host, username);
--- /dev/null
+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)
+);
--- /dev/null
+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 CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_archive_sh_username_timestamp ON archive (server_host, username, timestamp);
+CREATE INDEX i_archive_sh_username_peer ON archive (server_host, username, peer);
+CREATE INDEX i_archive_sh_username_bare_peer ON archive (server_host, username, bare_peer);
+CREATE INDEX i_archive_sh_timestamp ON archive (server_host, timestamp);
+
+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 CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host, username)
+);
--- /dev/null
+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 CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_muc_room_name_host ON muc_room (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 CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_muc_registered_nick ON muc_registered (nick);
+CREATE UNIQUE INDEX i_muc_registered_jid_host ON muc_registered (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 (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 (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,
+ host text NOT NULL,
+ jid text NOT NULL,
+ nick text NOT NULL,
+ nodes text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_muc_room_subscribers_host_jid ON muc_room_subscribers (host, jid);
+CREATE UNIQUE INDEX i_muc_room_subscribers_host_room_jid ON muc_room_subscribers (host, room, jid);
--- /dev/null
+CREATE TABLE spool (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ xml text NOT NULL,
+ seq SERIAL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_spool_sh_username ON spool (server_host, username);
--- /dev/null
+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 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 (
+ 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 (id);
--- /dev/null
+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 CURRENT_TIMESTAMP,
+ PRIMARY KEY (server_host, username, namespace)
+);
+
+CREATE INDEX i_private_storage_sh_username ON private_storage (server_host, username);
--- /dev/null
+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 (sid);
+CREATE INDEX i_proxy65_jid ON proxy65 (jid_i);
--- /dev/null
+CREATE TABLE pubsub_node (
+ host text NOT NULL,
+ node text NOT NULL,
+ parent text NOT NULL DEFAULT '',
+ plugin text NOT NULL,
+ nodeid SERIAL UNIQUE
+);
+CREATE INDEX i_pubsub_node_parent ON pubsub_node (parent);
+CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node (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 (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 (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 (jid);
+CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state (nodeid, jid);
+
+CREATE TABLE pubsub_item (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ itemid text NOT NULL,
+ publisher text NOT NULL,
+ creation varchar(32) NOT NULL,
+ modification varchar(32) NOT NULL,
+ payload text NOT NULL DEFAULT ''
+);
+CREATE INDEX i_pubsub_item_itemid ON pubsub_item (itemid);
+CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item (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 (subid, opt_name);
--- /dev/null
+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 (server_host, username, service, node);
--- /dev/null
+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 CURRENT_TIMESTAMP
+);
+
+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);
+
+
+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 (server_host, username, jid);
+
+CREATE TABLE roster_version (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ version text NOT NULL,
+ PRIMARY KEY (server_host, username)
+);
--- /dev/null
+CREATE TABLE sr_group (
+ name text NOT NULL,
+ server_host text NOT NULL,
+ opts text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ 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 CURRENT_TIMESTAMP,
+ PRIMARY KEY (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);
--- /dev/null
+CREATE TABLE vcard (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ vcard text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ 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);
--- /dev/null
+--
+-- 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.
+--
+
+CREATE TABLE users (
+ username text PRIMARY KEY,
+ "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()
+);
+
+-- 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 PRIMARY KEY,
+ seconds text NOT NULL,
+ state text NOT NULL
+);
+
+
+CREATE TABLE rosterusers (
+ username 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_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);
+
+
+CREATE TABLE rostergroups (
+ username text NOT NULL,
+ jid text NOT NULL,
+ grp text NOT NULL
+);
+
+CREATE INDEX pk_rosterg_user_jid ON rostergroups USING btree (username, jid);
+
+CREATE TABLE sr_group (
+ name text NOT NULL,
+ opts text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT now()
+);
+
+CREATE TABLE sr_user (
+ jid text NOT NULL,
+ grp text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT now()
+);
+
+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 (
+ username text NOT NULL,
+ xml text NOT NULL,
+ seq SERIAL,
+ created_at TIMESTAMP NOT NULL DEFAULT now()
+);
+
+CREATE INDEX i_despool ON spool USING btree (username);
+
+CREATE TABLE archive (
+ username 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_username_timestamp ON archive USING btree (username, timestamp);
+CREATE INDEX i_username_peer ON archive USING btree (username, peer);
+CREATE INDEX i_username_bare_peer ON archive USING btree (username, bare_peer);
+CREATE INDEX i_timestamp ON archive USING btree (timestamp);
+
+CREATE TABLE archive_prefs (
+ username text NOT NULL PRIMARY KEY,
+ def text NOT NULL,
+ always text NOT NULL,
+ never text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT now()
+);
+
+CREATE TABLE vcard (
+ username text PRIMARY KEY,
+ vcard text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT now()
+);
+
+CREATE TABLE vcard_search (
+ username text NOT NULL,
+ lusername text PRIMARY KEY,
+ 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
+);
+
+CREATE INDEX i_vcard_search_lfn ON vcard_search(lfn);
+CREATE INDEX i_vcard_search_lfamily ON vcard_search(lfamily);
+CREATE INDEX i_vcard_search_lgiven ON vcard_search(lgiven);
+CREATE INDEX i_vcard_search_lmiddle ON vcard_search(lmiddle);
+CREATE INDEX i_vcard_search_lnickname ON vcard_search(lnickname);
+CREATE INDEX i_vcard_search_lbday ON vcard_search(lbday);
+CREATE INDEX i_vcard_search_lctry ON vcard_search(lctry);
+CREATE INDEX i_vcard_search_llocality ON vcard_search(llocality);
+CREATE INDEX i_vcard_search_lemail ON vcard_search(lemail);
+CREATE INDEX i_vcard_search_lorgname ON vcard_search(lorgname);
+CREATE INDEX i_vcard_search_lorgunit ON vcard_search(lorgunit);
+
+CREATE TABLE privacy_default_list (
+ username text PRIMARY KEY,
+ name text NOT NULL
+);
+
+CREATE TABLE privacy_list (
+ username text NOT NULL,
+ name text NOT NULL,
+ id SERIAL UNIQUE,
+ 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 (
+ 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,
+ namespace text NOT NULL,
+ data text NOT NULL,
+ 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);
+
+
+CREATE TABLE roster_version (
+ username text PRIMARY KEY,
+ version text NOT NULL
+);
+
+-- 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 '',
+ plugin 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 varchar(32) NOT NULL,
+ modification varchar(32) 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,
+ 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,
+ 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,
+ 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,
+ 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 motd (
+ username text PRIMARY KEY,
+ xml text,
+ created_at TIMESTAMP NOT NULL DEFAULT now()
+);
+
+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
+);
+
+CREATE UNIQUE INDEX i_sm_sid ON sm USING btree (usec, pid);
+CREATE INDEX i_sm_node ON sm USING btree (node);
+CREATE INDEX i_sm_username ON sm USING btree (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,
+ resource text NOT NULL,
+ namespace text NOT NULL,
+ node text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_carboncopy_ur ON carboncopy USING btree (username, resource);
+CREATE INDEX i_carboncopy_user ON carboncopy USING btree (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,
+ timestamp bigint NOT NULL,
+ service text NOT NULL,
+ node text NOT NULL,
+ xml text NOT NULL
+);
+
+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);
--- /dev/null
+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 CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_users_sh_username ON "users" (server_host, username);
--- /dev/null
+CREATE TABLE oauth_token (
+ token text NOT NULL PRIMARY KEY,
+ jid text NOT NULL,
+ scope text NOT NULL,
+ "expire" bigint NOT NULL
+);
--- /dev/null
+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(domain, server_host, node, pid);
+CREATE INDEX i_route_domain ON route(domain);
--- /dev/null
+CREATE TABLE sm (
+ usec bigint NOT NULL,
+ pid text NOT NULL,
+ node text NOT NULL,
+ username text NOT NULL,
+ server_host text NOT NULL,
+ resource text NOT NULL,
+ priority text NOT NULL,
+ info text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_usec_pid ON sm(usec, pid);
+CREATE INDEX i_sm_node ON sm(node);
+CREATE INDEX i_sm_sh_username ON sm (server_host, username);
--- /dev/null
+CREATE TABLE motd (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ xml text,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_motd_sh_username ON motd (server_host, username);
--- /dev/null
+CREATE TABLE bosh (
+ sid text NOT NULL,
+ node text NOT NULL,
+ pid text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_bosh_sid ON bosh(sid);
--- /dev/null
+CREATE TABLE caps_features (
+ node text NOT NULL,
+ subnode text NOT NULL,
+ feature text,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_caps_features_node_subnode ON caps_features (node, subnode);
--- /dev/null
+CREATE TABLE carboncopy (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ resource text NOT NULL,
+ namespace text NOT NULL,
+ node text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_server_host_username_resource ON carboncopy (server_host, username, resource);
+CREATE INDEX i_carboncopy_sh_user ON carboncopy (server_host, username);
--- /dev/null
+CREATE TABLE last (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ seconds text NOT NULL,
+ state text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_last_sh_username ON last (server_host, username);
--- /dev/null
+CREATE TABLE archive (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ timestamp BIGINT UNSIGNED NOT NULL,
+ peer text NOT NULL,
+ bare_peer text NOT NULL,
+ xml text NOT NULL,
+ txt text,
+ id INTEGER PRIMARY KEY AUTOINCREMENT,
+ kind text,
+ nick text,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_archive_sh_username_timestamp ON archive (server_host, username, timestamp);
+CREATE INDEX i_archive_sh_username_peer ON archive (server_host, username, peer);
+CREATE INDEX i_archive_sh_username_bare_peer ON archive (server_host, username, bare_peer);
+CREATE INDEX i_archive_sh_timestamp ON archive (server_host, timestamp);
+
+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 CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_archive_prefs_sh_username ON archive_prefs (server_host, username);
--- /dev/null
+CREATE TABLE muc_room (
+ name text NOT NULL,
+ server_host text NOT NULL,
+ host text NOT NULL,
+ opts text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_muc_room_name_host ON muc_room (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 CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_muc_registered_nick ON muc_registered (nick);
+CREATE UNIQUE INDEX i_muc_registered_jid_host ON muc_registered (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 (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 (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,
+ host text NOT NULL,
+ jid text NOT NULL,
+ nick text NOT NULL,
+ nodes text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_muc_room_subscribers_host_jid ON muc_room_subscribers(host, jid);
+CREATE UNIQUE INDEX i_muc_room_subscribers_host_room_jid ON muc_room_subscribers(host, room, jid);
--- /dev/null
+CREATE TABLE spool (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ xml text NOT NULL,
+ seq INTEGER PRIMARY KEY AUTOINCREMENT,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_spool_sh_username ON spool (server_host, username);
--- /dev/null
+CREATE TABLE privacy_default_list (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ name text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_privacy_default_list_sh_user ON privacy_default_list (server_host, username);
+
+CREATE TABLE privacy_list (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ name text NOT NULL,
+ id INTEGER PRIMARY KEY AUTOINCREMENT,
+ 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 (
+ 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
+);
--- /dev/null
+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 CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_server_host_username_namespace ON private_storage (server_host, username, namespace);
+CREATE INDEX i_private_storage_sh_username ON private_storage (server_host, username);
--- /dev/null
+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 (sid);
+CREATE INDEX i_proxy65_jid ON proxy65 (jid_i);
--- /dev/null
+CREATE TABLE pubsub_node (
+ host text NOT NULL,
+ node text NOT NULL,
+ parent text NOT NULL DEFAULT '',
+ plugin text NOT NULL,
+ nodeid INTEGER PRIMARY KEY AUTOINCREMENT
+);
+CREATE INDEX i_pubsub_node_parent ON pubsub_node (parent);
+CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node (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 (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 (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 INTEGER PRIMARY KEY AUTOINCREMENT
+);
+CREATE INDEX i_pubsub_state_jid ON pubsub_state (jid);
+CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state (nodeid, jid);
+
+CREATE TABLE pubsub_item (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ itemid text NOT NULL,
+ publisher text NOT NULL,
+ creation varchar(32) NOT NULL,
+ modification varchar(32) NOT NULL,
+ payload text NOT NULL DEFAULT ''
+);
+CREATE INDEX i_pubsub_item_itemid ON pubsub_item (itemid);
+CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item (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 (subid, opt_name);
--- /dev/null
+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
+);
+
+CREATE UNIQUE INDEX i_server_host_username_timestamp ON push_session (server_host, username, timestamp);
+CREATE UNIQUE INDEX i_push_session_susn ON push_session (server_host, username, service, node);
--- /dev/null
+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 CURRENT_TIMESTAMP
+);
+
+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);
+
+
+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 (server_host, username, jid);
+
+CREATE TABLE roster_version (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ version text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_roster_version_sh_user ON roster_version (server_host, username);
--- /dev/null
+CREATE TABLE sr_group (
+ name text NOT NULL,
+ server_host text NOT NULL,
+ opts text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_server_host_name ON sr_group (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 CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_server_host_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);
--- /dev/null
+CREATE TABLE vcard (
+ username text NOT NULL,
+ server_host text NOT NULL,
+ vcard text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_vcard_sh_user ON vcard (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
+);
+
+CREATE UNIQUE INDEX i_server_host_lusername ON vcard_search (server_host, lusername);
+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);
--- /dev/null
+--
+-- 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.
+--
+
+CREATE TABLE users (
+ username text PRIMARY KEY,
+ 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 CURRENT_TIMESTAMP
+);
+
+
+CREATE TABLE last (
+ username text PRIMARY KEY,
+ seconds text NOT NULL,
+ state text NOT NULL
+);
+
+
+CREATE TABLE rosterusers (
+ username 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 CURRENT_TIMESTAMP
+);
+
+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);
+
+
+CREATE TABLE rostergroups (
+ username text NOT NULL,
+ jid text NOT NULL,
+ grp text NOT NULL
+);
+
+CREATE INDEX pk_rosterg_user_jid ON rostergroups (username, jid);
+
+CREATE TABLE sr_group (
+ name text NOT NULL,
+ opts text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE TABLE sr_user (
+ jid text NOT NULL,
+ grp text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+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 (
+ username text NOT NULL,
+ xml text NOT NULL,
+ seq INTEGER PRIMARY KEY AUTOINCREMENT,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_despool ON spool (username);
+
+CREATE TABLE archive (
+ username text NOT NULL,
+ timestamp BIGINT UNSIGNED NOT NULL,
+ peer text NOT NULL,
+ bare_peer text NOT NULL,
+ xml text NOT NULL,
+ txt text,
+ id INTEGER PRIMARY KEY AUTOINCREMENT,
+ kind text,
+ nick text,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_username_timestamp ON archive(username, timestamp);
+CREATE INDEX i_archive_username_peer ON archive (username, peer);
+CREATE INDEX i_archive_username_bare_peer ON archive (username, bare_peer);
+CREATE INDEX i_timestamp ON archive(timestamp);
+
+CREATE TABLE archive_prefs (
+ username text NOT NULL PRIMARY KEY,
+ def text NOT NULL,
+ always text NOT NULL,
+ never text NOT NULL,
+ created_at timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE TABLE vcard (
+ username text PRIMARY KEY,
+ vcard text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE TABLE vcard_search (
+ username text NOT NULL,
+ lusername text PRIMARY KEY,
+ 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
+);
+
+CREATE INDEX i_vcard_search_lfn ON vcard_search(lfn);
+CREATE INDEX i_vcard_search_lfamily ON vcard_search(lfamily);
+CREATE INDEX i_vcard_search_lgiven ON vcard_search(lgiven);
+CREATE INDEX i_vcard_search_lmiddle ON vcard_search(lmiddle);
+CREATE INDEX i_vcard_search_lnickname ON vcard_search(lnickname);
+CREATE INDEX i_vcard_search_lbday ON vcard_search(lbday);
+CREATE INDEX i_vcard_search_lctry ON vcard_search(lctry);
+CREATE INDEX i_vcard_search_llocality ON vcard_search(llocality);
+CREATE INDEX i_vcard_search_lemail ON vcard_search(lemail);
+CREATE INDEX i_vcard_search_lorgname ON vcard_search(lorgname);
+CREATE INDEX i_vcard_search_lorgunit ON vcard_search(lorgunit);
+
+CREATE TABLE privacy_default_list (
+ username text PRIMARY KEY,
+ name text NOT NULL
+);
+
+CREATE TABLE privacy_list (
+ username text NOT NULL,
+ name text NOT NULL,
+ id INTEGER PRIMARY KEY AUTOINCREMENT,
+ 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 (
+ 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 TABLE private_storage (
+ username text NOT NULL,
+ namespace text NOT NULL,
+ data text NOT NULL,
+ 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);
+
+
+CREATE TABLE roster_version (
+ username text PRIMARY KEY,
+ version text NOT NULL
+);
+
+CREATE TABLE pubsub_node (
+ host text NOT NULL,
+ node text NOT NULL,
+ parent text NOT NULL DEFAULT '',
+ plugin text NOT NULL,
+ nodeid INTEGER PRIMARY KEY AUTOINCREMENT
+);
+CREATE INDEX i_pubsub_node_parent ON pubsub_node (parent);
+CREATE UNIQUE INDEX i_pubsub_node_tuple ON pubsub_node (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 (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 (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 INTEGER PRIMARY KEY AUTOINCREMENT
+);
+CREATE INDEX i_pubsub_state_jid ON pubsub_state (jid);
+CREATE UNIQUE INDEX i_pubsub_state_tuple ON pubsub_state (nodeid, jid);
+
+CREATE TABLE pubsub_item (
+ nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE,
+ itemid text NOT NULL,
+ publisher text NOT NULL,
+ creation varchar(32) NOT NULL,
+ modification varchar(32) NOT NULL,
+ payload text NOT NULL DEFAULT ''
+);
+CREATE INDEX i_pubsub_item_itemid ON pubsub_item (itemid);
+CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item (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 (subid, opt_name);
+
+CREATE TABLE muc_room (
+ name text NOT NULL,
+ host text NOT NULL,
+ opts text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE UNIQUE INDEX i_muc_room_name_host ON muc_room (name, host);
+
+CREATE TABLE muc_registered (
+ jid text NOT NULL,
+ host text NOT NULL,
+ nick text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_muc_registered_nick ON muc_registered (nick);
+CREATE UNIQUE INDEX i_muc_registered_jid_host ON muc_registered (jid, host);
+
+CREATE TABLE muc_online_room (
+ name text NOT NULL,
+ 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 (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,
+ node text NOT NULL
+);
+
+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,
+ host text NOT NULL,
+ jid text NOT NULL,
+ nick text NOT NULL,
+ nodes text NOT NULL,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_muc_room_subscribers_host_jid ON muc_room_subscribers(host, jid);
+CREATE UNIQUE INDEX i_muc_room_subscribers_host_room_jid ON muc_room_subscribers(host, room, jid);
+
+CREATE TABLE motd (
+ username text PRIMARY KEY,
+ xml text,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE TABLE caps_features (
+ node text NOT NULL,
+ subnode text NOT NULL,
+ feature text,
+ created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
+);
+
+CREATE INDEX i_caps_features_node_subnode ON caps_features (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
+);
+
+CREATE UNIQUE INDEX i_sm_sid ON sm(usec, pid);
+CREATE INDEX i_sm_node ON sm(node);
+CREATE INDEX i_sm_username ON sm(username);
+
+CREATE TABLE oauth_token (
+ token text NOT NULL PRIMARY KEY,
+ jid text NOT NULL,
+ scope text NOT NULL,
+ expire bigint NOT NULL
+);
+
+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(domain, server_host, node, pid);
+CREATE INDEX i_route_domain ON route(domain);
+
+CREATE TABLE bosh (
+ sid text NOT NULL,
+ node text NOT NULL,
+ pid text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_bosh_sid ON bosh(sid);
+
+CREATE TABLE carboncopy (
+ username text NOT NULL,
+ resource text NOT NULL,
+ namespace text NOT NULL,
+ node text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_carboncopy_ur ON carboncopy (username, resource);
+CREATE INDEX i_carboncopy_user ON carboncopy (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 (sid);
+CREATE INDEX i_proxy65_jid ON proxy65 (jid_i);
+
+CREATE TABLE push_session (
+ username text NOT NULL,
+ timestamp bigint NOT NULL,
+ service text NOT NULL,
+ node text NOT NULL,
+ xml text NOT NULL
+);
+
+CREATE UNIQUE INDEX i_push_usn ON push_session (username, service, node);
+CREATE UNIQUE INDEX i_push_ut ON push_session (username, timestamp);