1
|
/**
|
2
|
* '$RCSfile$'
|
3
|
* Copyright: 2004 Regents of the University of California and the
|
4
|
* National Center for Ecological Analysis and Synthesis
|
5
|
*
|
6
|
* '$Author: berkley $'
|
7
|
* '$Date: 2011-02-02 15:52:50 -0800 (Wed, 02 Feb 2011) $'
|
8
|
* '$Revision: 5887 $'
|
9
|
*
|
10
|
* This program is free software; you can redistribute it and/or modify
|
11
|
* it under the terms of the GNU General Public License as published by
|
12
|
* the Free Software Foundation; either version 2 of the License, or
|
13
|
* (at your option) any later version.
|
14
|
*
|
15
|
* This program is distributed in the hope that it will be useful,
|
16
|
* but WITHOUT ANY WARRANTY; without even the implied warranty of
|
17
|
* MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
18
|
* GNU General Public License for more details.
|
19
|
*
|
20
|
* You should have received a copy of the GNU General Public License
|
21
|
* along with this program; if not, write to the Free Software
|
22
|
* Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA 02111-1307 USA
|
23
|
*/
|
24
|
|
25
|
/*
|
26
|
* Drop all of the objects in proper order
|
27
|
*/
|
28
|
set echo off
|
29
|
|
30
|
DROP SEQUENCE xml_nodes_id_seq;
|
31
|
DROP SEQUENCE xml_revisions_id_seq;
|
32
|
DROP SEQUENCE xml_catalog_id_seq;
|
33
|
DROP SEQUENCE xml_relation_id_seq;
|
34
|
DROP SEQUENCE xml_replication_id_seq;
|
35
|
DROP SEQUENCE access_log_id_seq;
|
36
|
DROP SEQUENCE xml_returnfield_id_seq;
|
37
|
DROP SEQUENCE xml_queryresult_id_seq;
|
38
|
DROP SEQUENCE xml_path_index_id_seq;
|
39
|
DROP SEQUENCE db_version_id_seq;
|
40
|
|
41
|
/* Drop triggers are not necessary */
|
42
|
DROP TRIGGER xml_nodes_before_insert;
|
43
|
DROP TRIGGER xml_revisions_before_insert;
|
44
|
DROP TRIGGER xml_catalog_before_insert;
|
45
|
DROP TRIGGER xml_relation_before_insert;
|
46
|
DROP TRIGGER xml_replication_before_insert;
|
47
|
DROP TRIGGER access_log_before_insert;
|
48
|
DROP TRIGGER xml_returnfield_before_insert;
|
49
|
DROP TRIGGER xml_queryresult_before_insert;
|
50
|
DROP TRIGGER db_version_before_insert;
|
51
|
|
52
|
|
53
|
DROP TABLE xml_index;
|
54
|
DROP TABLE xml_access;
|
55
|
DROP TABLE xml_accesssubtree;
|
56
|
DROP TABLE xml_revisions;
|
57
|
DROP TABLE xml_relation;
|
58
|
DROP TABLE xml_documents CASCADE CONSTRAINTS;
|
59
|
DROP TABLE xml_nodes;
|
60
|
DROP TABLE xml_nodes_revisions;
|
61
|
DROP TABLE xml_replication;
|
62
|
DROP TABLE xml_catalog;
|
63
|
DROP TABLE identifier;
|
64
|
DROP TABLE systemMetadata;
|
65
|
DROP TABLE access_log;
|
66
|
DROP TABLE harvest_site_schedule;
|
67
|
DROP TABLE harvest_detail_log;
|
68
|
DROP TABLE harvest_log;
|
69
|
DROP TABLE xml_queryresult;
|
70
|
DROP TABLE xml_returnfield;
|
71
|
DROP TABLE xml_path_index;
|
72
|
DROP TABLE db_version;
|
73
|
|
74
|
/*
|
75
|
*Replication -- table to store servers that metacat is replicated to
|
76
|
*/
|
77
|
CREATE TABLE xml_replication (
|
78
|
serverid NUMBER(20),
|
79
|
server VARCHAR2(512),
|
80
|
last_checked DATE,
|
81
|
replicate NUMBER(1),
|
82
|
datareplicate NUMBER(1),
|
83
|
hub NUMBER(1),
|
84
|
CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
|
85
|
);
|
86
|
|
87
|
CREATE SEQUENCE xml_replication_id_seq;
|
88
|
CREATE TRIGGER xml_replication_before_insert
|
89
|
BEFORE INSERT ON xml_replication FOR EACH ROW
|
90
|
BEGIN
|
91
|
SELECT xml_replication_id_seq.nextval
|
92
|
INTO :new.serverid
|
93
|
FROM dual;
|
94
|
END;
|
95
|
/
|
96
|
|
97
|
INSERT INTO xml_replication (server, replicate, datareplicate, hub)
|
98
|
VALUES ('localhost', '0', '0', '0');
|
99
|
|
100
|
/*
|
101
|
* Nodes -- table to store XML Nodes (both elements and attributes)
|
102
|
*/
|
103
|
CREATE SEQUENCE xml_nodes_id_seq;
|
104
|
CREATE TABLE xml_nodes (
|
105
|
nodeid NUMBER(20), -- the unique node id (pk)
|
106
|
nodeindex NUMBER(10), -- order of nodes within parent
|
107
|
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI,
|
108
|
-- ELEMENT, ATTRIBUTE, TEXT)
|
109
|
nodename VARCHAR2(250), -- the name of an element or attribute
|
110
|
nodeprefix VARCHAR2(50), -- the namespace prefix of an element
|
111
|
-- or attribute
|
112
|
nodedata VARCHAR2(4000), -- the data for this node (e.g.,
|
113
|
-- for TEXT it is the content)
|
114
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
115
|
rootnodeid NUMBER(20), -- index of the root node of this tree
|
116
|
docid VARCHAR2(250), -- index to the document id
|
117
|
date_created DATE,
|
118
|
date_updated DATE,
|
119
|
nodedatanumerical NUMBER, -- the data for this node if
|
120
|
-- it is a number
|
121
|
CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
|
122
|
CONSTRAINT xml_nodes_root_fk
|
123
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
|
124
|
CONSTRAINT xml_nodes_parent_fk
|
125
|
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
|
126
|
);
|
127
|
CREATE TRIGGER xml_nodes_before_insert
|
128
|
BEFORE INSERT ON xml_nodes FOR EACH ROW
|
129
|
BEGIN
|
130
|
SELECT xml_nodes_id_seq.nextval
|
131
|
INTO :new.nodeid
|
132
|
FROM dual;
|
133
|
END;
|
134
|
/
|
135
|
|
136
|
|
137
|
/*
|
138
|
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
|
139
|
*/
|
140
|
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
|
141
|
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
|
142
|
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
|
143
|
CREATE INDEX xml_nodes_idx4 ON xml_nodes (docid);
|
144
|
|
145
|
|
146
|
/*
|
147
|
* xml_nodes_revisions -- table to store nodes from xml_nodes which are of old revisions and deleted document
|
148
|
*/
|
149
|
|
150
|
CREATE TABLE xml_nodes_revisions (
|
151
|
nodeid NUMBER(20), -- the unique node id (pk)
|
152
|
nodeindex NUMBER(10), -- order of nodes within parent
|
153
|
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI,
|
154
|
-- ELEMENT, ATTRIBUTE, TEXT)
|
155
|
nodename VARCHAR2(250), -- the name of an element or attribute
|
156
|
nodeprefix VARCHAR2(50), -- the namespace prefix of an element
|
157
|
-- or attribute
|
158
|
nodedata VARCHAR2(4000), -- the data for this node (e.g.,
|
159
|
-- for TEXT it is the content)
|
160
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
161
|
rootnodeid NUMBER(20), -- index of the root node of this tree
|
162
|
docid VARCHAR2(250), -- index to the document id
|
163
|
date_created DATE,
|
164
|
date_updated DATE,
|
165
|
nodedatanumerical NUMBER, -- the data for this node if
|
166
|
-- it is a number
|
167
|
CONSTRAINT xml_nodes_revisions_pk PRIMARY KEY (nodeid),
|
168
|
CONSTRAINT xml_nodes_revisions_root_fk
|
169
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions,
|
170
|
CONSTRAINT xml_nodes_revisions_parent_fk
|
171
|
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes_revisions
|
172
|
);
|
173
|
|
174
|
|
175
|
/*
|
176
|
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes_revision
|
177
|
*/
|
178
|
CREATE INDEX xml_nodes_revisions_idx1 ON xml_nodes_revisions (rootnodeid);
|
179
|
CREATE INDEX xml_nodes_revisions_idx2 ON xml_nodes_revisions (parentnodeid);
|
180
|
CREATE INDEX xml_nodes_revisions_idx3 ON xml_nodes_revisions (nodename);
|
181
|
|
182
|
/*
|
183
|
* XML Catalog -- table to store all external sources for XML documents
|
184
|
*/
|
185
|
CREATE TABLE xml_catalog (
|
186
|
catalog_id NUMBER(20), -- the id for this catalog entry
|
187
|
entry_type VARCHAR2(500), -- the type of this catalog entry
|
188
|
-- (e.g., DTD, XSD, XSL)
|
189
|
source_doctype VARCHAR2(500), -- the source public_id for transforms
|
190
|
target_doctype VARCHAR2(500), -- the target public_id for transforms
|
191
|
public_id VARCHAR2(500), -- the unique id for this type
|
192
|
system_id VARCHAR2(1000), -- the local location of the object
|
193
|
CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
|
194
|
CONSTRAINT xml_catalog_uk UNIQUE
|
195
|
(entry_type, source_doctype, target_doctype, public_id)
|
196
|
);
|
197
|
|
198
|
CREATE SEQUENCE xml_catalog_id_seq;
|
199
|
|
200
|
CREATE TRIGGER xml_catalog_before_insert
|
201
|
BEFORE INSERT ON xml_catalog FOR EACH ROW
|
202
|
BEGIN
|
203
|
SELECT xml_catalog_id_seq.nextval
|
204
|
INTO :new.catalog_id
|
205
|
FROM dual;
|
206
|
END;
|
207
|
/
|
208
|
|
209
|
/*
|
210
|
* Documents -- table to store XML documents
|
211
|
*/
|
212
|
CREATE TABLE xml_documents (
|
213
|
docid VARCHAR2(250), -- the document id #
|
214
|
rootnodeid NUMBER(20), -- reference to root node of the DOM
|
215
|
docname VARCHAR2(100), -- usually the root element name
|
216
|
doctype VARCHAR2(100), -- public id indicating document type
|
217
|
user_owner VARCHAR2(100), -- the user owned the document
|
218
|
user_updated VARCHAR2(100), -- the user updated the document
|
219
|
server_location NUMBER(20), -- the server on which this document
|
220
|
-- originates
|
221
|
rev NUMBER(10) DEFAULT 1,--the revision number of the docume
|
222
|
date_created DATE,
|
223
|
date_updated DATE,
|
224
|
public_access NUMBER(1), -- flag for public access
|
225
|
catalog_id NUMBER(20), -- reference to xml_catalog
|
226
|
CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
|
227
|
CONSTRAINT xml_documents_rep_fk
|
228
|
FOREIGN KEY (server_location) REFERENCES xml_replication,
|
229
|
CONSTRAINT xml_documents_root_fk
|
230
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
|
231
|
CONSTRAINT xml_documents_catalog_fk
|
232
|
FOREIGN KEY (catalog_id) REFERENCES xml_catalog
|
233
|
);
|
234
|
|
235
|
/*
|
236
|
* Index of <docid,doctype> in xml_document
|
237
|
*/
|
238
|
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
|
239
|
CREATE INDEX xml_documents_idx2 ON xml_documents (lower(user_owner));
|
240
|
CREATE INDEX xml_documents_idx3 ON xml_documents (rootnodeid);
|
241
|
|
242
|
/*
|
243
|
* Revised Documents -- table to store XML documents saved after an UPDATE
|
244
|
* or DELETE
|
245
|
*/
|
246
|
CREATE TABLE xml_revisions (
|
247
|
revisionid NUMBER(20), -- the revision number we are saving
|
248
|
docid VARCHAR2(250), -- the document id #
|
249
|
rootnodeid NUMBER(20), -- reference to root node of the DOM
|
250
|
docname VARCHAR2(100), -- usually the root element name
|
251
|
doctype VARCHAR2(100), -- public id indicating document type
|
252
|
user_owner VARCHAR2(100),
|
253
|
user_updated VARCHAR2(100),
|
254
|
server_location NUMBER(20),
|
255
|
rev NUMBER(10),
|
256
|
date_created DATE,
|
257
|
date_updated DATE,
|
258
|
public_access NUMBER(1), -- flag for public access
|
259
|
catalog_id NUMBER(20), -- reference to xml_catalog
|
260
|
CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
|
261
|
CONSTRAINT xml_revisions_rep_fk
|
262
|
FOREIGN KEY (server_location) REFERENCES xml_replication,
|
263
|
CONSTRAINT xml_revisions_root_fk
|
264
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions,
|
265
|
CONSTRAINT xml_revisions_catalog_fk
|
266
|
FOREIGN KEY (catalog_id) REFERENCES xml_catalog
|
267
|
);
|
268
|
|
269
|
CREATE SEQUENCE xml_revisions_id_seq;
|
270
|
|
271
|
CREATE TRIGGER xml_revisions_before_insert
|
272
|
BEFORE INSERT ON xml_revisions FOR EACH ROW
|
273
|
BEGIN
|
274
|
SELECT xml_revisions_id_seq.nextval
|
275
|
INTO :new.revisionid
|
276
|
FROM dual;
|
277
|
END;
|
278
|
/
|
279
|
|
280
|
/*
|
281
|
* ACL -- table to store ACL for XML documents by principals
|
282
|
*/
|
283
|
CREATE TABLE xml_access (
|
284
|
docid VARCHAR2(250), -- the document id #
|
285
|
accessfileid VARCHAR2(250), -- the document id # for the access file
|
286
|
principal_name VARCHAR2(100), -- name of user, group, etc.
|
287
|
permission NUMBER(1), -- "read", "write", "all"
|
288
|
perm_type VARCHAR2(32), -- "allowed" or "denied"
|
289
|
perm_order VARCHAR2(32), -- "allow first" or "deny first"
|
290
|
begin_time DATE, -- the time that permission begins
|
291
|
end_time DATE, -- the time that permission ends
|
292
|
ticket_count NUMBER(5), -- ticket counter for that permission
|
293
|
subtreeid VARCHAR2(32), -- sub tree id
|
294
|
startnodeid NUMBER(20), -- start node for sub tree
|
295
|
endnodeid NUMBER(20), -- end node for sub tree
|
296
|
CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
|
297
|
CONSTRAINT xml_access_accessfileid_fk
|
298
|
FOREIGN KEY (accessfileid) REFERENCES xml_documents
|
299
|
);
|
300
|
CREATE INDEX xml_access_idx1 ON xml_access (lower(principal_name));
|
301
|
CREATE INDEX xml_access_idx2 ON xml_access (permission);
|
302
|
CREATE INDEX xml_access_idx3 ON xml_access (perm_type);
|
303
|
CREATE INDEX xml_access_idx4 ON xml_access (perm_order);
|
304
|
CREATE INDEX xml_access_idx5 ON xml_access (subtreeid);
|
305
|
|
306
|
|
307
|
/*
|
308
|
* Index of Nodes -- table to store precomputed paths through tree for
|
309
|
* quick searching in structured searches
|
310
|
*/
|
311
|
CREATE TABLE xml_index (
|
312
|
nodeid NUMBER(20), -- the unique node id
|
313
|
path VARCHAR2(1000), -- precomputed path through tree
|
314
|
docid VARCHAR2(250), -- index to the document id
|
315
|
doctype VARCHAR2(100), -- public id indicating document type
|
316
|
parentnodeid NUMBER(20), -- id of the parent of the node
|
317
|
-- represented by this row
|
318
|
CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
|
319
|
CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
|
320
|
CONSTRAINT xml_index_docid_fk
|
321
|
FOREIGN KEY (docid) REFERENCES xml_documents
|
322
|
);
|
323
|
|
324
|
/*
|
325
|
* Index of the paths in xml_index
|
326
|
*/
|
327
|
CREATE INDEX xml_index_idx1 ON xml_index (path);
|
328
|
CREATE INDEX xml_index_idx2 ON xml_index (docid);
|
329
|
CREATE INDEX xml_index_idx3 ON xml_index (nodeid);
|
330
|
|
331
|
|
332
|
/*
|
333
|
* Index of Paths - table to store nodes with paths specified by userst in metacat.properties
|
334
|
*/
|
335
|
CREATE TABLE xml_path_index (
|
336
|
nodeid NUMBER(20), -- the unique node id
|
337
|
docid VARCHAR2(250), -- index to the document id
|
338
|
path VARCHAR2(1000), -- precomputed path through tree
|
339
|
nodedata VARCHAR2(4000), -- the data for this node e.g.,
|
340
|
nodedatanumerical NUMBER(20), -- the data for this node if
|
341
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
342
|
CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid),
|
343
|
CONSTRAINT xml_path_index_docid_fk FOREIGN KEY (docid) REFERENCES xml_documents
|
344
|
);
|
345
|
|
346
|
|
347
|
/*
|
348
|
* create sequence an trigger
|
349
|
*/
|
350
|
CREATE SEQUENCE xml_path_index_id_seq;
|
351
|
CREATE TRIGGER xml_path_index_before_insert
|
352
|
BEFORE INSERT ON xml_path_index FOR EACH ROW
|
353
|
BEGIN
|
354
|
SELECT xml_path_index_id_seq.nextval
|
355
|
INTO :new.nodeid
|
356
|
FROM dual;
|
357
|
END;
|
358
|
/
|
359
|
|
360
|
|
361
|
/*
|
362
|
* Index of the path, nodedata, nodedatanumerical in xml_path_index
|
363
|
*/
|
364
|
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path);
|
365
|
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata);
|
366
|
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical);
|
367
|
|
368
|
|
369
|
|
370
|
CREATE TABLE xml_relation (
|
371
|
relationid NUMBER(20) PRIMARY KEY, -- unique id
|
372
|
docid VARCHAR2(250), -- the docid of the package file
|
373
|
-- that this relation came from
|
374
|
packagetype VARCHAR2(250), -- the type of the package
|
375
|
subject VARCHAR2(512) NOT NULL, -- the subject of the relation
|
376
|
subdoctype VARCHAR2(128), -- the doctype of the subject
|
377
|
relationship VARCHAR2(128) NOT NULL,-- the relationship type
|
378
|
object VARCHAR2(512) NOT NULL, -- the object of the relation
|
379
|
objdoctype VARCHAR2(128), -- the doctype of the object
|
380
|
CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
|
381
|
CONSTRAINT xml_relation_docid_fk
|
382
|
FOREIGN KEY (docid) REFERENCES xml_documents
|
383
|
);
|
384
|
|
385
|
CREATE SEQUENCE xml_relation_id_seq;
|
386
|
|
387
|
CREATE TRIGGER xml_relation_before_insert
|
388
|
BEFORE INSERT ON xml_relation FOR EACH ROW
|
389
|
BEGIN
|
390
|
SELECT xml_relation_id_seq.nextval
|
391
|
INTO :new.relationid
|
392
|
FROM dual;
|
393
|
END;
|
394
|
/
|
395
|
|
396
|
/*
|
397
|
* Table used to store all document identifiers for system metadata objects
|
398
|
* similar restraints to identifier. Cannot use identifier table for this
|
399
|
* purpose because then you have to worry about whether you insert the
|
400
|
* data first or the systemMetadata first.
|
401
|
*/
|
402
|
CREATE TABLE systemMetadata (
|
403
|
guid VARCHAR2(2000), -- the globally unique string identifier
|
404
|
docid VARCHAR(250), -- the local document id #
|
405
|
rev NUMBER(8), -- the revision part of the local identifier
|
406
|
date_uploaded DATE, -- the date/time the document was first submitted
|
407
|
rights_holder VARCHAR2(250), --the user who has rights to the document, usually the first persons to upload it
|
408
|
checksum VARCHAR2(512), --the checksum of the doc using the given algorithm (see below)
|
409
|
checksum_algorithm VARCHAR2(250), --the algorithm used to calculate the checksum
|
410
|
origin_member_node VARCHAR2(250), --the member node where the document was first uploaded
|
411
|
authoritive_member_node VARCHAR2(250), --the member node that currently controls the document
|
412
|
date_modified DATE, -- the last date/time that the file was changed
|
413
|
submitter VARCHAR2(256) -- the user who originally submitted the doc
|
414
|
)
|
415
|
|
416
|
/*
|
417
|
* Table used to store all document identifiers in metacat. Each identifier
|
418
|
* has a globally unique, unconstrained string, which we will refer to as a
|
419
|
* GUID, and a local metacat identifier, which consists of the docid
|
420
|
* and revision fields. Each row maps one global identifier to the local
|
421
|
* identifier (docid) used within metacat.
|
422
|
*/
|
423
|
CREATE TABLE identifier (
|
424
|
guid VARCHAR2(2000), -- the globally unique string identifier
|
425
|
docid VARCHAR2(250), -- the local document id #
|
426
|
rev NUMBER(8) -- the revision part of the local identifier
|
427
|
);
|
428
|
|
429
|
/*
|
430
|
* accesssubtree -- table to store access subtree info
|
431
|
*/
|
432
|
CREATE TABLE xml_accesssubtree (
|
433
|
docid VARCHAR2(250), -- the document id #
|
434
|
rev NUMBER(10) DEFAULT 1, --the revision number of the docume
|
435
|
controllevel VARCHAR2(50), -- the level it control -- document or subtree
|
436
|
subtreeid VARCHAR2(250), -- the subtree id
|
437
|
startnodeid NUMBER(20), -- the start node id of access subtree
|
438
|
endnodeid NUMBER(20), -- the end node if of access subtree
|
439
|
CONSTRAINT xml_accesssubtree_docid_fk
|
440
|
FOREIGN KEY (docid) REFERENCES xml_documents
|
441
|
);
|
442
|
|
443
|
/*
|
444
|
* Returnfields -- table to store combinations of returnfields requested
|
445
|
* and the number of times this table is accessed
|
446
|
*/
|
447
|
CREATE TABLE xml_returnfield (
|
448
|
returnfield_id NUMBER(20), -- the id for this returnfield entry
|
449
|
returnfield_string VARCHAR2(2000), -- the returnfield string
|
450
|
usage_count NUMBER(20), -- the number of times this string
|
451
|
-- has been requested
|
452
|
CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id)
|
453
|
);
|
454
|
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string);
|
455
|
|
456
|
CREATE SEQUENCE xml_returnfield_id_seq;
|
457
|
|
458
|
CREATE TRIGGER xml_returnfield_before_insert
|
459
|
BEFORE INSERT ON xml_returnfield FOR EACH ROW
|
460
|
BEGIN
|
461
|
SELECT xml_returnfield_id_seq.nextval
|
462
|
INTO :new.returnfield_id
|
463
|
FROM dual;
|
464
|
END;
|
465
|
/
|
466
|
|
467
|
/*
|
468
|
* Queryresults -- table to store queryresults for a given docid
|
469
|
* and returnfield_id
|
470
|
*/
|
471
|
CREATE TABLE xml_queryresult(
|
472
|
queryresult_id NUMBER(20), -- id for this entry
|
473
|
returnfield_id NUMBER(20), -- id for the returnfield corresponding to this entry
|
474
|
docid VARCHAR2(250), -- docid of the document
|
475
|
queryresult_string VARCHAR2(4000), -- resultant text generated for this docid and given
|
476
|
-- returnfield
|
477
|
CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id),
|
478
|
CONSTRAINT xml_queryresult_searchid_fk
|
479
|
FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield
|
480
|
);
|
481
|
|
482
|
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid);
|
483
|
|
484
|
CREATE SEQUENCE xml_queryresult_id_seq;
|
485
|
|
486
|
CREATE TRIGGER xml_queryresult_before_insert
|
487
|
BEFORE INSERT ON xml_queryresult FOR EACH ROW
|
488
|
BEGIN
|
489
|
SELECT xml_queryresult_id_seq.nextval
|
490
|
INTO :new.queryresult_id
|
491
|
FROM dual;
|
492
|
END;
|
493
|
/
|
494
|
|
495
|
|
496
|
|
497
|
|
498
|
/*
|
499
|
* Logging -- table to store metadata and data access log
|
500
|
*/
|
501
|
CREATE TABLE access_log (
|
502
|
entryid NUMBER(20), -- the identifier for the log event
|
503
|
ip_address VARCHAR2(512), -- the ip address inititiating the event
|
504
|
principal VARCHAR2(512), -- the user initiiating the event
|
505
|
docid VARCHAR2(250), -- the document id #
|
506
|
event VARCHAR2(512), -- the code symbolizing the event type
|
507
|
date_logged DATE, -- the datetime on which the event occurred
|
508
|
CONSTRAINT access_log_pk PRIMARY KEY (entryid)
|
509
|
);
|
510
|
|
511
|
CREATE SEQUENCE access_log_id_seq;
|
512
|
CREATE TRIGGER access_log_before_insert
|
513
|
BEFORE INSERT ON access_log FOR EACH ROW
|
514
|
BEGIN
|
515
|
SELECT access_log_id_seq.nextval
|
516
|
INTO :new.entryid
|
517
|
FROM dual;
|
518
|
END;
|
519
|
/
|
520
|
|
521
|
/*
|
522
|
* harvest_site_schedule -- table to store harvest sites and schedule info
|
523
|
*/
|
524
|
CREATE TABLE harvest_site_schedule (
|
525
|
site_schedule_id NUMBER, -- unique id
|
526
|
documentlisturl VARCHAR2(255), -- URL of the site harvest document list
|
527
|
ldapdn VARCHAR2(255), -- LDAP distinguished name for site account
|
528
|
datenextharvest DATE, -- scheduled date of next harvest
|
529
|
datelastharvest DATE, -- recorded date of last harvest
|
530
|
updatefrequency NUMBER, -- the harvest update frequency
|
531
|
unit VARCHAR2(50), -- update unit -- days weeks or months
|
532
|
contact_email VARCHAR2(50), -- email address of the site contact person
|
533
|
ldappwd VARCHAR2(20), -- LDAP password for site account
|
534
|
CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
|
535
|
);
|
536
|
|
537
|
/*
|
538
|
* harvest_log -- table to log entries for harvest operations
|
539
|
*/
|
540
|
CREATE TABLE harvest_log (
|
541
|
harvest_log_id NUMBER, -- unique id
|
542
|
harvest_date DATE, -- date of the current harvest
|
543
|
status NUMBER, -- non-zero indicates an error status
|
544
|
message VARCHAR2(1000), -- text message for this log entry
|
545
|
harvest_operation_code VARCHAR2(30), -- the type of harvest operation
|
546
|
site_schedule_id NUMBER, -- site schedule id, or 0 if no site
|
547
|
CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
|
548
|
);
|
549
|
|
550
|
/*
|
551
|
* harvest_detail_log -- table to log detailed info about documents that
|
552
|
* generated errors during the harvest
|
553
|
*/
|
554
|
CREATE TABLE harvest_detail_log (
|
555
|
detail_log_id NUMBER, -- unique id
|
556
|
harvest_log_id NUMBER, -- ponter to the related log entry
|
557
|
scope VARCHAR2(50), -- document scope
|
558
|
identifier NUMBER, -- document identifier
|
559
|
revision NUMBER, -- document revision
|
560
|
document_url VARCHAR2(255), -- document URL
|
561
|
error_message VARCHAR2(1000), -- text error message
|
562
|
document_type VARCHAR2(100), -- document type
|
563
|
CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
|
564
|
CONSTRAINT harvest_detail_log_fk
|
565
|
FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
|
566
|
);
|
567
|
|
568
|
/*
|
569
|
* db_version -- table to store the version history of this database
|
570
|
*/
|
571
|
CREATE TABLE db_version (
|
572
|
db_version_id NUMBER(20), -- the identifier for the version
|
573
|
version VARCHAR(250), -- the version number
|
574
|
status NUMBER(20), -- status of the version
|
575
|
date_created DATE, -- the datetime on which the version was created
|
576
|
CONSTRAINT db_version_pk PRIMARY KEY (db_version_id)
|
577
|
);
|
578
|
|
579
|
CREATE SEQUENCE db_version_id_seq;
|
580
|
CREATE TRIGGER db_version_before_insert
|
581
|
BEFORE INSERT ON db_version FOR EACH ROW
|
582
|
BEGIN
|
583
|
SELECT db_version_id_seq.nextval
|
584
|
INTO :new.db_version_id
|
585
|
FROM dual;
|
586
|
END;
|
587
|
/
|
588
|
|
589
|
/*
|
590
|
* scheduled_job -- table to store scheduled jobs
|
591
|
*/
|
592
|
CREATE TABLE scheduled_job (
|
593
|
id NUMBER(20) NOT NULL default nextval('scheduled_job_id_seq'),
|
594
|
date_created TIMESTAMP NOT NULL,
|
595
|
date_updated TIMESTAMP NOT NULL,
|
596
|
status VARCHAR2(64) NOT NULL,
|
597
|
name VARCHAR2(512) NOT NULL,
|
598
|
trigger_name VARCHAR2(512) NOT NULL,
|
599
|
group_name VARCHAR2(512) NOT NULL,
|
600
|
class_name VARCHAR2(1024) NOT NULL,
|
601
|
start_time TIMESTAMP NOT NULL,
|
602
|
interval_value NUMBER NOT NULL,
|
603
|
interval_unit VARCHAR2(8) NOT NULL,
|
604
|
CONSTRAINT scheduled_job_pk PRIMARY KEY (id),
|
605
|
CONSTRAINT scheduled_job_uk UNIQUE (name)
|
606
|
);
|
607
|
|
608
|
CREATE SEQUENCE scheduled_job_id_seq;
|
609
|
CREATE TRIGGER scheduled_job_before_insert
|
610
|
BEFORE INSERT ON scheduled_job FOR EACH ROW
|
611
|
BEGIN
|
612
|
SELECT scheduled_job_id_seq.nextval
|
613
|
INTO :new.id
|
614
|
FROM dual;
|
615
|
END;
|
616
|
/
|
617
|
|
618
|
/*
|
619
|
* scheduled_job_params -- table to store scheduled job parameters
|
620
|
*/
|
621
|
CREATE TABLE scheduled_job_params (
|
622
|
id NUMBER(20) NOT NULL default nextval('scheduled_job_params_id_seq'),
|
623
|
date_created TIMESTAMP NOT NULL,
|
624
|
date_updated TIMESTAMP NOT NULL,
|
625
|
status VARCHAR2(64) NOT NULL,
|
626
|
job_id NUMBER(20) NOT NULL,
|
627
|
key VARCHAR2(64) NOT NULL,
|
628
|
value VARCHAR2(1024) NOT NULL,
|
629
|
CONSTRAINT scheduled_job_params_pk PRIMARY KEY (id),
|
630
|
CONSTRAINT scheduled_job_params_fk
|
631
|
FOREIGN KEY (job_id) REFERENCES scheduled_job(id)
|
632
|
);
|
633
|
|
634
|
CREATE SEQUENCE scheduled_job_params_id_seq;
|
635
|
CREATE TRIGGER scheduled_job_params_before_insert
|
636
|
BEFORE INSERT ON scheduled_job_params FOR EACH ROW
|
637
|
BEGIN
|
638
|
SELECT scheduled_job_id_params_seq.nextval
|
639
|
INTO :new.id
|
640
|
FROM dual;
|
641
|
END;
|
642
|
/
|
643
|
|