Project

General

Profile

1
/*
2
 * xmltables-sqlserver.sql
3
 *             : Create or replace tables for storing XML in MS SQL Server
4
 *
5
 *      Purpose: creates tables needed for storing XML in MS SQL Server database
6
 * 
7
 *      Created: 25 May 2001
8
 *       Author: Jivka Bojilova
9
 * Organization: National Center for Ecological Analysis and Synthesis
10
 *    Copyright: 2000 Regents of the University of California and the
11
 *               National Center for Ecological Analysis and Synthesis
12
 *  For Details: http://www.nceas.ucsb.edu/
13
 *    File Info: '$Id: xmltables-sqlserver.sql 1740 2003-07-20 01:50:09Z tao $'
14
 *
15
 */
16

    
17
/*
18
 * Drop all of the objects in proper order
19
 */
20
drop table [dbo].[xml_index];
21
drop table [dbo].[xml_access];
22
drop table [dbo].[xml_revisions];
23
drop table [dbo].[xml_relation];
24
drop table [dbo].[xml_documents];
25
drop table [dbo].[xml_nodes];
26
drop table [dbo].[xml_replication];
27
drop table [dbo].[xml_catalog];
28
drop table [dbo].[accession_number];
29
drop table [dbo].[xml_accesssubtree];
30

    
31
/* 
32
 * ACL -- table to store ACL for XML documents by principals
33
 */
34
CREATE TABLE [dbo].[xml_access] (
35
  [docid]		[varchar] (250) NULL ,
36
  [accessfileid]	[varchar] (250) NULL ,
37
  [principal_name]	[varchar] (100) NULL ,
38
  [permission]		[int] NULL ,
39
  [perm_type]		[varchar] (50) NULL ,
40
  [perm_order]		[varchar] (50) NULL ,
41
  [begin_time]		[datetime] NULL ,
42
  [end_time]		[datetime] NULL ,
43
  [ticket_count]	[int] NULL 
44
  [subtreeid]  [varchar] (250) NULL ,
45
  [startnodeid]  [bigint] NULL ,
46
  [endnodeid]  [bigint] NULL
47
) ON [PRIMARY]
48
GO
49

    
50
/* 
51
 * accesssubtree -- table to store access subtree info 
52
 */
53
CREATE TABLE [dbo].[xml_accesssubtree] (
54
  [docid]		[varchar] (250) NULL ,
55
  [rev]			[int] NULL , 		
56
  [controllevel]		[varchar] (250) NULL , 
57
  [subtreeid]		[varchar] (250) NULL ,
58
	[startnodeid]  [bigint] NULL ,
59
  [endnodeid]  [bigint] NULL
60
)
61
GO
62

    
63
/* 
64
 * XML Catalog -- table to store all external sources for XML documents
65
 */
66
CREATE TABLE [dbo].[xml_catalog] (
67
  [catalog_id]		[bigint] IDENTITY (1, 1) NOT NULL ,
68
  [entry_type]		[varchar] (50) NULL ,
69
  [source_doctype]	[varchar] (250) NULL ,
70
  [target_doctype]	[varchar] (250) NULL ,
71
  [public_id]		[varchar] (250) NULL ,
72
  [system_id]		[varchar] (512) NULL 
73
) ON [PRIMARY]
74
GO
75

    
76
/* 
77
 * Documents -- table to store XML documents
78
 */
79
CREATE TABLE [dbo].[xml_documents] (
80
  [docid]		[varchar] (250) NOT NULL ,
81
  [rootnodeid]		[bigint] NULL ,
82
  [docname]		[varchar] (100) NULL ,
83
  [doctype]		[varchar] (100) NULL ,
84
  [user_owner]		[varchar] (100) NULL ,
85
  [user_updated]	[varchar] (100) NULL ,
86
  [server_location]	[bigint] NULL ,
87
  [rev]			[int] NULL ,
88
  [date_created]	[datetime] NULL ,
89
  [date_updated]	[datetime] NULL ,
90
  [public_access]	[bit] NULL ,
91
  [catalog_id]		[bigint] NULL 
92
) ON [PRIMARY]
93
GO
94

    
95
/* 
96
 * Index of Nodes -- table to store precomputed paths through tree for 
97
 * quick searching in structured searches
98
 */
99
CREATE TABLE [dbo].[xml_index] (
100
  [nodeid]		[bigint] NOT NULL ,
101
  [path]		[varchar] (200) NOT NULL ,
102
  [docid]		[varchar] (250) NULL ,
103
  [doctype]		[varchar] (100) NULL ,
104
  [parentnodeid]	[bigint] NULL 
105
) ON [PRIMARY]
106
GO
107

    
108
/* 
109
 * Nodes -- table to store XML Nodes (both elements and attributes)
110
 */
111
CREATE TABLE [dbo].[xml_nodes] (
112
  [nodeid]		[bigint] IDENTITY (1, 1) NOT NULL ,
113
  [nodeindex]		[int] NULL ,
114
  [nodetype]		[varchar] (20) NULL ,
115
  [nodename]		[varchar] (250) NULL ,
116
  [nodedata]		[varchar] (4000) NULL ,
117
  [parentnodeid]	[bigint] NULL ,
118
  [rootnodeid]		[bigint] NULL ,
119
  [docid]		[varchar] (250) NULL ,
120
  [date_created]	[datetime] NULL ,
121
  [date_updated]	[datetime] NULL 
122
) ON [PRIMARY]
123
GO
124

    
125
/* 
126
 * Relations -- table to store relations of form <subject,relationship,object>
127
 */
128
CREATE TABLE [dbo].[xml_relation] (
129
  [relationid]		[bigint] IDENTITY (1, 1) NOT NULL ,
130
  [docid]		[varchar] (250) NULL ,
131
  [packagetype]		[varchar] (250) NULL ,
132
  [subject]		[varchar] (250) NOT NULL ,
133
  [subdoctype]		[varchar] (128) NULL ,
134
  [relationship]	[varchar] (128) NOT NULL ,
135
  [object]		[varchar] (250) NOT NULL ,
136
  [objdoctype]		[varchar] (128) NULL 
137
) ON [PRIMARY]
138
GO
139

    
140
/* 
141
 * Replication -- table to store servers that metacat is replicated to
142
 */
143
CREATE TABLE [dbo].[xml_replication] (
144
  [serverid]		[bigint] IDENTITY (1, 1) NOT NULL ,
145
  [server]		[varchar] (512) NULL ,
146
  [last_checked]	[datetime] NULL ,
147
  [replicate]  [bit] NULL
148
  [datareplicate]  [bit] NULL
149
  [hub]  [bit] NULL
150
) ON [PRIMARY]
151
GO
152
     
153
set identity_insert xml_replication on
154
INSERT INTO xml_replication (serverid, server, replicate, datareplicate, hub) VALUES ('1', 'localhost', '0', '0', '0');
155
set identity_insert xml_replication off 
156

    
157
/* 
158
 * Revised Documents -- table to store XML documents saved after an UPDATE
159
 *                    or DELETE
160
 */
161
CREATE TABLE [dbo].[xml_revisions] (
162
  [revisionid]		[bigint] IDENTITY (1, 1) NOT NULL ,
163
  [docid]		[varchar] (250) NULL ,
164
  [rootnodeid]		[bigint] NULL ,
165
  [docname]		[varchar] (100) NULL ,
166
  [doctype]		[varchar] (100) NULL ,
167
  [user_owner]		[varchar] (100) NULL ,
168
  [user_updated]	[varchar] (100) NULL ,
169
  [server_location]	[bigint] NULL ,
170
  [rev]			[int] NULL ,
171
  [date_created]	[datetime] NULL ,
172
  [date_updated]	[datetime] NULL ,
173
  [public_access]	[bit] NULL ,
174
  [catalog_id]		[bigint] NULL 
175
) ON [PRIMARY]
176
GO                                
177

    
178
/* 
179
 * Table used as Unique ID generator for the uniqueid part of Accession#
180
 */
181
CREATE TABLE [dbo].[accession_number] (
182
  [uniqueid]		[int] IDENTITY (1, 1) NOT NULL,
183
  [site_code]		[varchar] (100),
184
  [date_created]	[datetime],
185
  CONSTRAINT [PK_accession_number] PRIMARY KEY CLUSTERED ([uniqueid])
186
) ON [PRIMARY]
187
GO
188

    
189
/* 
190
 * Constraints and indexes
191
 */
192
ALTER TABLE [dbo].[xml_catalog] WITH NOCHECK ADD 
193
	CONSTRAINT [PK_xml_catalog] PRIMARY KEY  CLUSTERED 
194
	(
195
		[catalog_id]
196
	)  ON [PRIMARY] 
197
GO
198

    
199
ALTER TABLE [dbo].[xml_documents] WITH NOCHECK ADD 
200
	CONSTRAINT [PK_xml_documents] PRIMARY KEY  CLUSTERED 
201
	(
202
		[docid]
203
	)  ON [PRIMARY] 
204
GO
205

    
206
ALTER TABLE [dbo].[xml_index] WITH NOCHECK ADD 
207
	CONSTRAINT [PK_xml_index] PRIMARY KEY  CLUSTERED 
208
	(
209
		[nodeid],
210
		[path]
211
	)  ON [PRIMARY] 
212
GO
213

    
214
ALTER TABLE [dbo].[xml_nodes] WITH NOCHECK ADD 
215
	CONSTRAINT [PK_xml_nodes] PRIMARY KEY  CLUSTERED 
216
	(
217
		[nodeid]
218
	)  ON [PRIMARY] 
219
GO
220

    
221
ALTER TABLE [dbo].[xml_relation] WITH NOCHECK ADD 
222
	CONSTRAINT [PK_xml_relation] PRIMARY KEY  CLUSTERED 
223
	(
224
		[relationid]
225
	)  ON [PRIMARY] 
226
GO
227

    
228
ALTER TABLE [dbo].[xml_replication] WITH NOCHECK ADD 
229
	CONSTRAINT [PK_xml_replication] PRIMARY KEY  CLUSTERED 
230
	(
231
		[serverid]
232
	)  ON [PRIMARY] 
233
GO
234

    
235
ALTER TABLE [dbo].[xml_revisions] WITH NOCHECK ADD 
236
	CONSTRAINT [PK_xml_revisions] PRIMARY KEY  CLUSTERED 
237
	(
238
		[revisionid]
239
	)  ON [PRIMARY] 
240
GO
241

    
242
ALTER TABLE [dbo].[xml_access] WITH NOCHECK ADD 
243
	CONSTRAINT [CK_xml_access] CHECK ([begin_time] < [end_time])
244
GO
245

    
246
ALTER TABLE [dbo].[xml_catalog] WITH NOCHECK ADD 
247
	CONSTRAINT [IX_xml_catalog] UNIQUE  NONCLUSTERED 
248
	(
249
		[entry_type],
250
		[source_doctype],
251
		[target_doctype],
252
		[public_id]
253
	)  ON [PRIMARY] 
254
GO
255

    
256
ALTER TABLE [dbo].[xml_documents] WITH NOCHECK ADD 
257
	CONSTRAINT [DF_xml_documents_rev] DEFAULT (1) FOR [rev]
258
GO
259

    
260
ALTER TABLE [dbo].[xml_accesssubtree] WITH NOCHECK ADD 
261
	CONSTRAINT [DF_xml_accesssubtree_rev] DEFAULT (1) FOR [rev]
262
GO
263

    
264
ALTER TABLE [dbo].[xml_relation] WITH NOCHECK ADD 
265
	CONSTRAINT [IX_xml_relation] UNIQUE  NONCLUSTERED 
266
	(
267
		[docid],
268
    [subject],
269
		[relationship],
270
		[object]
271
	)  ON [PRIMARY] 
272
GO
273

    
274
 CREATE  INDEX [IX_xml_documents] ON [dbo].[xml_documents]([docid], [doctype])
275
                                                                    ON [PRIMARY]
276
GO
277

    
278
 CREATE  INDEX [IX_xml_index] ON [dbo].[xml_index]([path]) ON [PRIMARY]
279
GO
280

    
281
 CREATE  INDEX [IX1_xml_nodes] ON [dbo].[xml_nodes]([rootnodeid]) ON [PRIMARY]
282
GO
283

    
284
 CREATE  INDEX [IX2_xml_nodes] ON [dbo].[xml_nodes]([parentnodeid]) ON [PRIMARY]
285
GO
286

    
287
 CREATE  INDEX [IX3_xml_nodes] ON [dbo].[xml_nodes]([nodename]) ON [PRIMARY]
288
GO
289

    
290
ALTER TABLE [dbo].[xml_accesssubtree] ADD 
291
	CONSTRAINT [FK_xml_accesssubtree_xml_documents] FOREIGN KEY
292
  (
293
		[docid]
294
	) REFERENCES [dbo].[xml_documents] (
295
		[docid]
296
	)
297
GO
298

    
299
ALTER TABLE [dbo].[xml_access] ADD 
300
	CONSTRAINT [FK_xml_access_xml_documents] FOREIGN KEY 
301
	(
302
		[accessfileid]
303
	) REFERENCES [dbo].[xml_documents] (
304
		[docid]
305
	)
306
GO
307

    
308
ALTER TABLE [dbo].[xml_documents] ADD 
309
	CONSTRAINT [FK_xml_documents_xml_catalog] FOREIGN KEY 
310
	(
311
		[catalog_id]
312
	) REFERENCES [dbo].[xml_catalog] (
313
		[catalog_id]
314
	),
315
	CONSTRAINT [FK_xml_documents_xml_nodes] FOREIGN KEY 
316
	(
317
		[rootnodeid]
318
	) REFERENCES [dbo].[xml_nodes] (
319
		[nodeid]
320
	),
321
	CONSTRAINT [FK_xml_documents_xml_replication] FOREIGN KEY 
322
	(
323
		[server_location]
324
	) REFERENCES [dbo].[xml_replication] (
325
		[serverid]
326
	)
327
GO
328

    
329
ALTER TABLE [dbo].[xml_index] ADD 
330
	CONSTRAINT [FK_xml_index_xml_documents] FOREIGN KEY 
331
	(
332
		[docid]
333
	) REFERENCES [dbo].[xml_documents] (
334
		[docid]
335
	),
336
	CONSTRAINT [FK_xml_index_xml_nodes] FOREIGN KEY 
337
	(
338
		[nodeid]
339
	) REFERENCES [dbo].[xml_nodes] (
340
		[nodeid]
341
	)
342
GO
343

    
344
ALTER TABLE [dbo].[xml_nodes] ADD 
345
	CONSTRAINT [FK_xml_nodes_parentnodeid] FOREIGN KEY 
346
	(
347
		[parentnodeid]
348
	) REFERENCES [dbo].[xml_nodes] (
349
		[nodeid]
350
	),
351
	CONSTRAINT [FK_xml_nodes_rootnodeid] FOREIGN KEY 
352
	(
353
		[rootnodeid]
354
	) REFERENCES [dbo].[xml_nodes] (
355
		[nodeid]
356
	)
357
GO
358

    
359
ALTER TABLE [dbo].[xml_relation] ADD 
360
	CONSTRAINT [FK_xml_relation_xml_documents] FOREIGN KEY 
361
	(
362
		[docid]
363
	) REFERENCES [dbo].[xml_documents] (
364
		[docid]
365
	)
366
GO
367

    
368
ALTER TABLE [dbo].[xml_revisions] ADD 
369
	CONSTRAINT [FK_xml_revisions_xml_catalog] FOREIGN KEY 
370
	(
371
		[catalog_id]
372
	) REFERENCES [dbo].[xml_catalog] (
373
		[catalog_id]
374
	),
375
	CONSTRAINT [FK_xml_revisions_xml_nodes] FOREIGN KEY 
376
	(
377
		[rootnodeid]
378
	) REFERENCES [dbo].[xml_nodes] (
379
		[nodeid]
380
	),
381
	CONSTRAINT [FK_xml_revisions_xml_replication] FOREIGN KEY 
382
	(
383
		[server_location]
384
	) REFERENCES [dbo].[xml_replication] (
385
		[serverid]
386
	)
387
GO
388

    
(17-17/19)