mssql.initial.sql 13 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400
  1. CREATE TABLE [dbo].[cache] (
  2. [user_id] [int] NOT NULL ,
  3. [cache_key] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  4. [expires] [datetime] NULL ,
  5. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL
  6. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  7. GO
  8. CREATE TABLE [dbo].[cache_shared] (
  9. [cache_key] [varchar] (255) COLLATE Latin1_General_CI_AI NOT NULL ,
  10. [expires] [datetime] NULL ,
  11. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL
  12. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  13. GO
  14. CREATE TABLE [dbo].[cache_index] (
  15. [user_id] [int] NOT NULL ,
  16. [mailbox] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  17. [expires] [datetime] NULL ,
  18. [valid] [char] (1) COLLATE Latin1_General_CI_AI NOT NULL ,
  19. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL
  20. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  21. GO
  22. CREATE TABLE [dbo].[cache_thread] (
  23. [user_id] [int] NOT NULL ,
  24. [mailbox] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  25. [expires] [datetime] NULL ,
  26. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL
  27. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  28. GO
  29. CREATE TABLE [dbo].[cache_messages] (
  30. [user_id] [int] NOT NULL ,
  31. [mailbox] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  32. [uid] [int] NOT NULL ,
  33. [expires] [datetime] NULL ,
  34. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL ,
  35. [flags] [int] NOT NULL
  36. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  37. GO
  38. CREATE TABLE [dbo].[contacts] (
  39. [contact_id] [int] IDENTITY (1, 1) NOT NULL ,
  40. [user_id] [int] NOT NULL ,
  41. [changed] [datetime] NOT NULL ,
  42. [del] [char] (1) COLLATE Latin1_General_CI_AI NOT NULL ,
  43. [name] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  44. [email] [varchar] (8000) COLLATE Latin1_General_CI_AI NOT NULL ,
  45. [firstname] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  46. [surname] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  47. [vcard] [text] COLLATE Latin1_General_CI_AI NULL ,
  48. [words] [text] COLLATE Latin1_General_CI_AI NULL
  49. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  50. GO
  51. CREATE TABLE [dbo].[contactgroups] (
  52. [contactgroup_id] [int] IDENTITY (1, 1) NOT NULL ,
  53. [user_id] [int] NOT NULL ,
  54. [changed] [datetime] NOT NULL ,
  55. [del] [char] (1) COLLATE Latin1_General_CI_AI NOT NULL ,
  56. [name] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL
  57. ) ON [PRIMARY]
  58. GO
  59. CREATE TABLE [dbo].[contactgroupmembers] (
  60. [contactgroup_id] [int] NOT NULL ,
  61. [contact_id] [int] NOT NULL ,
  62. [created] [datetime] NOT NULL
  63. ) ON [PRIMARY]
  64. GO
  65. CREATE TABLE [dbo].[identities] (
  66. [identity_id] [int] IDENTITY (1, 1) NOT NULL ,
  67. [user_id] [int] NOT NULL ,
  68. [changed] [datetime] NOT NULL ,
  69. [del] [char] (1) COLLATE Latin1_General_CI_AI NOT NULL ,
  70. [standard] [char] (1) COLLATE Latin1_General_CI_AI NOT NULL ,
  71. [name] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  72. [organization] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  73. [email] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  74. [reply-to] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  75. [bcc] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  76. [signature] [text] COLLATE Latin1_General_CI_AI NULL,
  77. [html_signature] [char] (1) COLLATE Latin1_General_CI_AI NOT NULL
  78. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  79. GO
  80. CREATE TABLE [dbo].[session] (
  81. [sess_id] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  82. [created] [datetime] NOT NULL ,
  83. [changed] [datetime] NULL ,
  84. [ip] [varchar] (40) COLLATE Latin1_General_CI_AI NOT NULL ,
  85. [vars] [text] COLLATE Latin1_General_CI_AI NOT NULL
  86. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  87. GO
  88. CREATE TABLE [dbo].[users] (
  89. [user_id] [int] IDENTITY (1, 1) NOT NULL ,
  90. [username] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  91. [mail_host] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  92. [created] [datetime] NOT NULL ,
  93. [last_login] [datetime] NULL ,
  94. [failed_login] [datetime] NULL ,
  95. [failed_login_counter] [int] NULL ,
  96. [language] [varchar] (5) COLLATE Latin1_General_CI_AI NULL ,
  97. [preferences] [text] COLLATE Latin1_General_CI_AI NULL
  98. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  99. GO
  100. CREATE TABLE [dbo].[dictionary] (
  101. [user_id] [int] ,
  102. [language] [varchar] (5) COLLATE Latin1_General_CI_AI NOT NULL ,
  103. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL
  104. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  105. GO
  106. CREATE TABLE [dbo].[searches] (
  107. [search_id] [int] IDENTITY (1, 1) NOT NULL ,
  108. [user_id] [int] NOT NULL ,
  109. [type] [tinyint] NOT NULL ,
  110. [name] [varchar] (128) COLLATE Latin1_General_CI_AI NOT NULL ,
  111. [data] [text] COLLATE Latin1_General_CI_AI NOT NULL
  112. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  113. GO
  114. CREATE TABLE [dbo].[system] (
  115. [name] [varchar] (64) COLLATE Latin1_General_CI_AI NOT NULL ,
  116. [value] [text] COLLATE Latin1_General_CI_AI NOT NULL
  117. ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
  118. GO
  119. ALTER TABLE [dbo].[cache] WITH NOCHECK ADD
  120. PRIMARY KEY CLUSTERED
  121. (
  122. [user_id],[cache_key]
  123. ) ON [PRIMARY]
  124. GO
  125. ALTER TABLE [dbo].[cache_shared] WITH NOCHECK ADD
  126. PRIMARY KEY CLUSTERED
  127. (
  128. [cache_key]
  129. ) ON [PRIMARY]
  130. GO
  131. ALTER TABLE [dbo].[cache_index] WITH NOCHECK ADD
  132. PRIMARY KEY CLUSTERED
  133. (
  134. [user_id],[mailbox]
  135. ) ON [PRIMARY]
  136. GO
  137. ALTER TABLE [dbo].[cache_thread] WITH NOCHECK ADD
  138. PRIMARY KEY CLUSTERED
  139. (
  140. [user_id],[mailbox]
  141. ) ON [PRIMARY]
  142. GO
  143. ALTER TABLE [dbo].[cache_messages] WITH NOCHECK ADD
  144. PRIMARY KEY CLUSTERED
  145. (
  146. [user_id],[mailbox],[uid]
  147. ) ON [PRIMARY]
  148. GO
  149. ALTER TABLE [dbo].[contacts] WITH NOCHECK ADD
  150. CONSTRAINT [PK_contacts_contact_id] PRIMARY KEY CLUSTERED
  151. (
  152. [contact_id]
  153. ) ON [PRIMARY]
  154. GO
  155. ALTER TABLE [dbo].[contactgroups] WITH NOCHECK ADD
  156. CONSTRAINT [PK_contactgroups_contactgroup_id] PRIMARY KEY CLUSTERED
  157. (
  158. [contactgroup_id]
  159. ) ON [PRIMARY]
  160. GO
  161. ALTER TABLE [dbo].[contactgroupmembers] WITH NOCHECK ADD
  162. CONSTRAINT [PK_contactgroupmembers_id] PRIMARY KEY CLUSTERED
  163. (
  164. [contactgroup_id], [contact_id]
  165. ) ON [PRIMARY]
  166. GO
  167. ALTER TABLE [dbo].[identities] WITH NOCHECK ADD
  168. PRIMARY KEY CLUSTERED
  169. (
  170. [identity_id]
  171. ) ON [PRIMARY]
  172. GO
  173. ALTER TABLE [dbo].[session] WITH NOCHECK ADD
  174. CONSTRAINT [PK_session_sess_id] PRIMARY KEY CLUSTERED
  175. (
  176. [sess_id]
  177. ) ON [PRIMARY]
  178. GO
  179. ALTER TABLE [dbo].[users] WITH NOCHECK ADD
  180. CONSTRAINT [PK_users_user_id] PRIMARY KEY CLUSTERED
  181. (
  182. [user_id]
  183. ) ON [PRIMARY]
  184. GO
  185. ALTER TABLE [dbo].[searches] WITH NOCHECK ADD
  186. CONSTRAINT [PK_searches_search_id] PRIMARY KEY CLUSTERED
  187. (
  188. [search_id]
  189. ) ON [PRIMARY]
  190. GO
  191. ALTER TABLE [dbo].[system] WITH NOCHECK ADD
  192. CONSTRAINT [PK_system_name] PRIMARY KEY CLUSTERED
  193. (
  194. [name]
  195. ) ON [PRIMARY]
  196. GO
  197. ALTER TABLE [dbo].[cache] ADD
  198. CONSTRAINT [DF_cache_user_id] DEFAULT ('0') FOR [user_id],
  199. CONSTRAINT [DF_cache_cache_key] DEFAULT ('') FOR [cache_key],
  200. GO
  201. ALTER TABLE [dbo].[cache_index] ADD
  202. CONSTRAINT [DF_cache_index_valid] DEFAULT ('0') FOR [valid]
  203. GO
  204. ALTER TABLE [dbo].[cache_messages] ADD
  205. CONSTRAINT [DF_cache_messages_flags] DEFAULT (0) FOR [flags]
  206. GO
  207. CREATE INDEX [IX_cache_shared_cache_key] ON [dbo].[cache_shared]([cache_key]) ON [PRIMARY]
  208. GO
  209. CREATE INDEX [IX_cache_index_user_id] ON [dbo].[cache_index]([user_id]) ON [PRIMARY]
  210. GO
  211. CREATE INDEX [IX_cache_thread_user_id] ON [dbo].[cache_thread]([user_id]) ON [PRIMARY]
  212. GO
  213. CREATE INDEX [IX_cache_messages_user_id] ON [dbo].[cache_messages]([user_id]) ON [PRIMARY]
  214. GO
  215. CREATE INDEX [IX_cache_expires] ON [dbo].[cache]([expires]) ON [PRIMARY]
  216. GO
  217. CREATE INDEX [IX_cache_shared_expires] ON [dbo].[cache_shared]([expires]) ON [PRIMARY]
  218. GO
  219. CREATE INDEX [IX_cache_index_expires] ON [dbo].[cache_index]([expires]) ON [PRIMARY]
  220. GO
  221. CREATE INDEX [IX_cache_thread_expires] ON [dbo].[cache_thread]([expires]) ON [PRIMARY]
  222. GO
  223. CREATE INDEX [IX_cache_messages_expires] ON [dbo].[cache_messages]([expires]) ON [PRIMARY]
  224. GO
  225. ALTER TABLE [dbo].[contacts] ADD
  226. CONSTRAINT [DF_contacts_user_id] DEFAULT (0) FOR [user_id],
  227. CONSTRAINT [DF_contacts_changed] DEFAULT (getdate()) FOR [changed],
  228. CONSTRAINT [DF_contacts_del] DEFAULT ('0') FOR [del],
  229. CONSTRAINT [DF_contacts_name] DEFAULT ('') FOR [name],
  230. CONSTRAINT [DF_contacts_email] DEFAULT ('') FOR [email],
  231. CONSTRAINT [DF_contacts_firstname] DEFAULT ('') FOR [firstname],
  232. CONSTRAINT [DF_contacts_surname] DEFAULT ('') FOR [surname],
  233. CONSTRAINT [CK_contacts_del] CHECK ([del] = '1' or [del] = '0')
  234. GO
  235. CREATE INDEX [IX_contacts_user_id] ON [dbo].[contacts]([user_id]) ON [PRIMARY]
  236. GO
  237. ALTER TABLE [dbo].[contactgroups] ADD
  238. CONSTRAINT [DF_contactgroups_user_id] DEFAULT (0) FOR [user_id],
  239. CONSTRAINT [DF_contactgroups_changed] DEFAULT (getdate()) FOR [changed],
  240. CONSTRAINT [DF_contactgroups_del] DEFAULT ('0') FOR [del],
  241. CONSTRAINT [DF_contactgroups_name] DEFAULT ('') FOR [name],
  242. CONSTRAINT [CK_contactgroups_del] CHECK ([del] = '1' or [del] = '0')
  243. GO
  244. CREATE INDEX [IX_contactgroups_user_id] ON [dbo].[contactgroups]([user_id]) ON [PRIMARY]
  245. GO
  246. ALTER TABLE [dbo].[contactgroupmembers] ADD
  247. CONSTRAINT [DF_contactgroupmembers_contactgroup_id] DEFAULT (0) FOR [contactgroup_id],
  248. CONSTRAINT [DF_contactgroupmembers_contact_id] DEFAULT (0) FOR [contact_id],
  249. CONSTRAINT [DF_contactgroupmembers_created] DEFAULT (getdate()) FOR [created]
  250. GO
  251. CREATE INDEX [IX_contactgroupmembers_contact_id] ON [dbo].[contactgroupmembers]([contact_id]) ON [PRIMARY]
  252. GO
  253. ALTER TABLE [dbo].[identities] ADD
  254. CONSTRAINT [DF_identities_user] DEFAULT ('0') FOR [user_id],
  255. CONSTRAINT [DF_identities_del] DEFAULT ('0') FOR [del],
  256. CONSTRAINT [DF_identities_standard] DEFAULT ('0') FOR [standard],
  257. CONSTRAINT [DF_identities_name] DEFAULT ('') FOR [name],
  258. CONSTRAINT [DF_identities_organization] DEFAULT ('') FOR [organization],
  259. CONSTRAINT [DF_identities_email] DEFAULT ('') FOR [email],
  260. CONSTRAINT [DF_identities_reply] DEFAULT ('') FOR [reply-to],
  261. CONSTRAINT [DF_identities_bcc] DEFAULT ('') FOR [bcc],
  262. CONSTRAINT [DF_identities_html_signature] DEFAULT ('0') FOR [html_signature],
  263. CHECK ([standard] = '1' or [standard] = '0'),
  264. CHECK ([del] = '1' or [del] = '0')
  265. GO
  266. CREATE INDEX [IX_identities_user_id] ON [dbo].[identities]([user_id]) ON [PRIMARY]
  267. GO
  268. CREATE INDEX [IX_identities_email] ON [dbo].[identities]([email],[del]) ON [PRIMARY]
  269. GO
  270. ALTER TABLE [dbo].[session] ADD
  271. CONSTRAINT [DF_session_sess_id] DEFAULT ('') FOR [sess_id],
  272. CONSTRAINT [DF_session_ip] DEFAULT ('') FOR [ip]
  273. GO
  274. CREATE INDEX [IX_session_changed] ON [dbo].[session]([changed]) ON [PRIMARY]
  275. GO
  276. ALTER TABLE [dbo].[users] ADD
  277. CONSTRAINT [DF_users_username] DEFAULT ('') FOR [username],
  278. CONSTRAINT [DF_users_mail_host] DEFAULT ('') FOR [mail_host],
  279. CONSTRAINT [DF_users_created] DEFAULT (getdate()) FOR [created]
  280. GO
  281. CREATE UNIQUE INDEX [IX_users_username] ON [dbo].[users]([username],[mail_host]) ON [PRIMARY]
  282. GO
  283. CREATE UNIQUE INDEX [IX_dictionary_user_language] ON [dbo].[dictionary]([user_id],[language]) ON [PRIMARY]
  284. GO
  285. ALTER TABLE [dbo].[searches] ADD
  286. CONSTRAINT [DF_searches_user] DEFAULT (0) FOR [user_id],
  287. CONSTRAINT [DF_searches_type] DEFAULT (0) FOR [type]
  288. GO
  289. CREATE UNIQUE INDEX [IX_searches_user_type_name] ON [dbo].[searches]([user_id],[type],[name]) ON [PRIMARY]
  290. GO
  291. ALTER TABLE [dbo].[identities] ADD CONSTRAINT [FK_identities_user_id]
  292. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  293. ON DELETE CASCADE ON UPDATE CASCADE
  294. GO
  295. ALTER TABLE [dbo].[contacts] ADD CONSTRAINT [FK_contacts_user_id]
  296. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  297. ON DELETE CASCADE ON UPDATE CASCADE
  298. GO
  299. ALTER TABLE [dbo].[contactgroups] ADD CONSTRAINT [FK_contactgroups_user_id]
  300. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  301. ON DELETE CASCADE ON UPDATE CASCADE
  302. GO
  303. ALTER TABLE [dbo].[cache] ADD CONSTRAINT [FK_cache_user_id]
  304. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  305. ON DELETE CASCADE ON UPDATE CASCADE
  306. GO
  307. ALTER TABLE [dbo].[cache_index] ADD CONSTRAINT [FK_cache_index_user_id]
  308. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  309. ON DELETE CASCADE ON UPDATE CASCADE
  310. GO
  311. ALTER TABLE [dbo].[cache_thread] ADD CONSTRAINT [FK_cache_thread_user_id]
  312. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  313. ON DELETE CASCADE ON UPDATE CASCADE
  314. GO
  315. ALTER TABLE [dbo].[cache_messages] ADD CONSTRAINT [FK_cache_messages_user_id]
  316. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  317. ON DELETE CASCADE ON UPDATE CASCADE
  318. GO
  319. ALTER TABLE [dbo].[contactgroupmembers] ADD CONSTRAINT [FK_contactgroupmembers_contactgroup_id]
  320. FOREIGN KEY ([contactgroup_id]) REFERENCES [dbo].[contactgroups] ([contactgroup_id])
  321. ON DELETE CASCADE ON UPDATE CASCADE
  322. GO
  323. ALTER TABLE [dbo].[searches] ADD CONSTRAINT [FK_searches_user_id]
  324. FOREIGN KEY ([user_id]) REFERENCES [dbo].[users] ([user_id])
  325. ON DELETE CASCADE ON UPDATE CASCADE
  326. GO
  327. -- Use trigger instead of foreign key (#1487112)
  328. -- "Introducing FOREIGN KEY constraint ... may cause cycles or multiple cascade paths."
  329. CREATE TRIGGER [contact_delete_member] ON [dbo].[contacts]
  330. AFTER DELETE AS
  331. DELETE FROM [dbo].[contactgroupmembers]
  332. WHERE [contact_id] IN (SELECT [contact_id] FROM deleted)
  333. GO
  334. INSERT INTO [dbo].[system] ([name], [value]) VALUES ('roundcube-version', '2016112200')
  335. GO