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 2112 2004-04-08 16:23:49Z costa $'
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_accesssubtree];
23
drop table [dbo].[xml_revisions];
24
drop table [dbo].[xml_relation];
25
drop table [dbo].[xml_documents];
26
drop table [dbo].[xml_nodes];
27
drop table [dbo].[xml_replication];
28
drop table [dbo].[xml_catalog];
29
drop table [dbo].[accession_number];
30
drop table [dbo].[harvest_site_schedule];
31
drop table [dbo].[harvest_log];
32
drop table [dbo].[harvest_detail_log];
33

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

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

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

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

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

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

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

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

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

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

    
193
/* 
194
 * harvest_site_schedule -- table to store harvest sites and schedule info
195
 */
196
CREATE TABLE [dbo].[harvest_site_schedule] (
197
  [site_schedule_id]    [int] IDENTITY (1, 1) NOT NULL ,
198
  [documentlisturl]		[varchar] (250) NOT NULL ,
199
  [ldapdn]		        [varchar] (250) NOT NULL ,
200
  [datenextharvest]		[datetime] NULL ,
201
  [datelastharvest]	    [datetime] NULL ,
202
  [updatefrequency]		[int] NULL ,
203
  [unit]                [varchar] (50) NULL ,
204
  [contact_email]		[varchar] (50) NULL ,
205
  [ldappwd]		        [varchar] (20) NOT NULL 
206
) ON [PRIMARY]
207
GO
208

    
209
/* 
210
 * harvest_log -- table to log entries for harvest operations
211
 */
212
CREATE TABLE [dbo].[harvest_log] (
213
  [harvest_log_id]         [int] IDENTITY (1, 1) NOT NULL ,
214
  [harvest_date]		   [datetime] NOT NULL ,
215
  [status]		           [int] NOT NULL ,
216
  [message]		           [varchar] (1000) NULL ,
217
  [harvest_operation_code] [varchar] (30) NOT NULL ,
218
  [site_schedule_id]       [int] NOT NULL 
219
) ON [PRIMARY]
220
GO
221

    
222
/* 
223
 * harvest_detail_log -- table to log detailed info about documents that
224
 *                       generated errors during the harvest
225
 */
226
CREATE TABLE [dbo].[harvest_detail_log] (
227
  [detail_log_id]   [int] IDENTITY (1, 1) NOT NULL ,
228
  [harvest_log_id]	[int] NOT NULL ,
229
  [scope]		    [varchar] (50) NOT NULL ,
230
  [identifier]		[bigint] NOT NULL ,
231
  [revision]	    [bigint] NOT NULL ,
232
  [document_url]	[varchar] (255) NOT NULL ,
233
  [error_message]   [varchar] (1000) NOT NULL ,
234
  [document_type]   [varchar] (100) NOT NULL 
235
) ON [PRIMARY]
236
GO
237

    
238
/* 
239
 * Constraints and indexes
240
 */
241
ALTER TABLE [dbo].[xml_catalog] WITH NOCHECK ADD 
242
	CONSTRAINT [PK_xml_catalog] PRIMARY KEY  CLUSTERED 
243
	(
244
		[catalog_id]
245
	)  ON [PRIMARY] 
246
GO
247

    
248
ALTER TABLE [dbo].[xml_documents] WITH NOCHECK ADD 
249
	CONSTRAINT [PK_xml_documents] PRIMARY KEY  CLUSTERED 
250
	(
251
		[docid]
252
	)  ON [PRIMARY] 
253
GO
254

    
255
ALTER TABLE [dbo].[xml_index] WITH NOCHECK ADD 
256
	CONSTRAINT [PK_xml_index] PRIMARY KEY  CLUSTERED 
257
	(
258
		[nodeid],
259
		[path]
260
	)  ON [PRIMARY] 
261
GO
262

    
263
ALTER TABLE [dbo].[xml_nodes] WITH NOCHECK ADD 
264
	CONSTRAINT [PK_xml_nodes] PRIMARY KEY  CLUSTERED 
265
	(
266
		[nodeid]
267
	)  ON [PRIMARY] 
268
GO
269

    
270
ALTER TABLE [dbo].[xml_relation] WITH NOCHECK ADD 
271
	CONSTRAINT [PK_xml_relation] PRIMARY KEY  CLUSTERED 
272
	(
273
		[relationid]
274
	)  ON [PRIMARY] 
275
GO
276

    
277
ALTER TABLE [dbo].[xml_replication] WITH NOCHECK ADD 
278
	CONSTRAINT [PK_xml_replication] PRIMARY KEY  CLUSTERED 
279
	(
280
		[serverid]
281
	)  ON [PRIMARY] 
282
GO
283

    
284
ALTER TABLE [dbo].[xml_revisions] WITH NOCHECK ADD 
285
	CONSTRAINT [PK_xml_revisions] PRIMARY KEY  CLUSTERED 
286
	(
287
		[revisionid]
288
	)  ON [PRIMARY] 
289
GO
290

    
291
ALTER TABLE [dbo].[harvest_site_schedule] WITH NOCHECK ADD 
292
	CONSTRAINT [PK_harvest_site_schedule] PRIMARY KEY  CLUSTERED 
293
	(
294
		[site_schedule_id]
295
	)  ON [PRIMARY] 
296
GO
297

    
298
ALTER TABLE [dbo].[harvest_log] WITH NOCHECK ADD 
299
	CONSTRAINT [PK_harvest_log] PRIMARY KEY  CLUSTERED 
300
	(
301
		[harvest_log_id]
302
	)  ON [PRIMARY] 
303
GO
304

    
305
ALTER TABLE [dbo].[harvest_detail_log] WITH NOCHECK ADD 
306
	CONSTRAINT [PK_harvest_detail_log] PRIMARY KEY  CLUSTERED 
307
	(
308
		[detail_log_id]
309
	)  ON [PRIMARY] 
310
GO
311

    
312
ALTER TABLE [dbo].[xml_access] WITH NOCHECK ADD 
313
	CONSTRAINT [CK_xml_access] CHECK ([begin_time] < [end_time])
314
GO
315

    
316
ALTER TABLE [dbo].[xml_catalog] WITH NOCHECK ADD 
317
	CONSTRAINT [IX_xml_catalog] UNIQUE  NONCLUSTERED 
318
	(
319
		[entry_type],
320
		[source_doctype],
321
		[target_doctype],
322
		[public_id]
323
	)  ON [PRIMARY] 
324
GO
325

    
326
ALTER TABLE [dbo].[xml_documents] WITH NOCHECK ADD 
327
	CONSTRAINT [DF_xml_documents_rev] DEFAULT (1) FOR [rev]
328
GO
329

    
330
ALTER TABLE [dbo].[xml_accesssubtree] WITH NOCHECK ADD 
331
	CONSTRAINT [DF_xml_accesssubtree_rev] DEFAULT (1) FOR [rev]
332
GO
333

    
334
ALTER TABLE [dbo].[xml_relation] WITH NOCHECK ADD 
335
	CONSTRAINT [IX_xml_relation] UNIQUE  NONCLUSTERED 
336
	(
337
		[docid],
338
    [subject],
339
		[relationship],
340
		[object]
341
	)  ON [PRIMARY] 
342
GO
343

    
344
 CREATE  INDEX [IX_xml_documents] ON [dbo].[xml_documents]([docid], [doctype])
345
                                                                    ON [PRIMARY]
346
GO
347

    
348
 CREATE  INDEX [IX_xml_index] ON [dbo].[xml_index]([path]) ON [PRIMARY]
349
GO
350

    
351
 CREATE  INDEX [IX1_xml_nodes] ON [dbo].[xml_nodes]([rootnodeid]) ON [PRIMARY]
352
GO
353

    
354
 CREATE  INDEX [IX2_xml_nodes] ON [dbo].[xml_nodes]([parentnodeid]) ON [PRIMARY]
355
GO
356

    
357
 CREATE  INDEX [IX3_xml_nodes] ON [dbo].[xml_nodes]([nodename]) ON [PRIMARY]
358
GO
359

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

    
369
ALTER TABLE [dbo].[xml_access] ADD 
370
	CONSTRAINT [FK_xml_access_xml_documents] FOREIGN KEY 
371
	(
372
		[accessfileid]
373
	) REFERENCES [dbo].[xml_documents] (
374
		[docid]
375
	)
376
GO
377

    
378
ALTER TABLE [dbo].[xml_documents] ADD 
379
	CONSTRAINT [FK_xml_documents_xml_catalog] FOREIGN KEY 
380
	(
381
		[catalog_id]
382
	) REFERENCES [dbo].[xml_catalog] (
383
		[catalog_id]
384
	),
385
	CONSTRAINT [FK_xml_documents_xml_nodes] FOREIGN KEY 
386
	(
387
		[rootnodeid]
388
	) REFERENCES [dbo].[xml_nodes] (
389
		[nodeid]
390
	),
391
	CONSTRAINT [FK_xml_documents_xml_replication] FOREIGN KEY 
392
	(
393
		[server_location]
394
	) REFERENCES [dbo].[xml_replication] (
395
		[serverid]
396
	)
397
GO
398

    
399
ALTER TABLE [dbo].[xml_index] ADD 
400
	CONSTRAINT [FK_xml_index_xml_documents] FOREIGN KEY 
401
	(
402
		[docid]
403
	) REFERENCES [dbo].[xml_documents] (
404
		[docid]
405
	),
406
	CONSTRAINT [FK_xml_index_xml_nodes] FOREIGN KEY 
407
	(
408
		[nodeid]
409
	) REFERENCES [dbo].[xml_nodes] (
410
		[nodeid]
411
	)
412
GO
413

    
414
ALTER TABLE [dbo].[xml_nodes] ADD 
415
	CONSTRAINT [FK_xml_nodes_parentnodeid] FOREIGN KEY 
416
	(
417
		[parentnodeid]
418
	) REFERENCES [dbo].[xml_nodes] (
419
		[nodeid]
420
	),
421
	CONSTRAINT [FK_xml_nodes_rootnodeid] FOREIGN KEY 
422
	(
423
		[rootnodeid]
424
	) REFERENCES [dbo].[xml_nodes] (
425
		[nodeid]
426
	)
427
GO
428

    
429
ALTER TABLE [dbo].[xml_relation] ADD 
430
	CONSTRAINT [FK_xml_relation_xml_documents] FOREIGN KEY 
431
	(
432
		[docid]
433
	) REFERENCES [dbo].[xml_documents] (
434
		[docid]
435
	)
436
GO
437

    
438
ALTER TABLE [dbo].[xml_revisions] ADD 
439
	CONSTRAINT [FK_xml_revisions_xml_catalog] FOREIGN KEY 
440
	(
441
		[catalog_id]
442
	) REFERENCES [dbo].[xml_catalog] (
443
		[catalog_id]
444
	),
445
	CONSTRAINT [FK_xml_revisions_xml_nodes] FOREIGN KEY 
446
	(
447
		[rootnodeid]
448
	) REFERENCES [dbo].[xml_nodes] (
449
		[nodeid]
450
	),
451
	CONSTRAINT [FK_xml_revisions_xml_replication] FOREIGN KEY 
452
	(
453
		[server_location]
454
	) REFERENCES [dbo].[xml_replication] (
455
		[serverid]
456
	)
457
GO
458

    
459
ALTER TABLE [dbo].[harvest_detail_log] ADD 
460
	CONSTRAINT [FK_harvest_detail_log_harvest_log] FOREIGN KEY 
461
	(
462
		[harvest_log_id]
463
	) REFERENCES [dbo].[harvest_log] (
464
		[harvest_log_id]
465
	)
466
GO
467

    
(23-23/24)