metacat / src / xmltables-oracle.sql @ 6693
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: leinfelder $'
|
7 |
* '$Date: 2011-10-27 17:51:48 -0700 (Thu, 27 Oct 2011) $'
|
8 |
* '$Revision: 6561 $'
|
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 |
systemmetadatareplicate NUMBER(1),
|
84 |
hub NUMBER(1),
|
85 |
CONSTRAINT xml_replication_pk PRIMARY KEY (serverid) |
86 |
); |
87 |
|
88 |
CREATE SEQUENCE xml_replication_id_seq;
|
89 |
CREATE TRIGGER xml_replication_before_insert |
90 |
BEFORE INSERT ON xml_replication FOR EACH ROW |
91 |
BEGIN
|
92 |
SELECT xml_replication_id_seq.nextval
|
93 |
INTO :new.serverid
|
94 |
FROM dual;
|
95 |
END;
|
96 |
/ |
97 |
|
98 |
INSERT INTO xml_replication (server, replicate, datareplicate, systemmetadatareplicate, hub) |
99 |
VALUES ('localhost', '0', '0', '0', '0'); |
100 |
|
101 |
/*
|
102 |
* Nodes -- table to store XML Nodes (both elements and attributes)
|
103 |
*/
|
104 |
CREATE SEQUENCE xml_nodes_id_seq;
|
105 |
CREATE TABLE xml_nodes ( |
106 |
nodeid NUMBER(20), -- the unique node id (pk) |
107 |
nodeindex NUMBER(10), -- order of nodes within parent |
108 |
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI, |
109 |
-- ELEMENT, ATTRIBUTE, TEXT)
|
110 |
nodename VARCHAR2(250), -- the name of an element or attribute |
111 |
nodeprefix VARCHAR2(50), -- the namespace prefix of an element |
112 |
-- or attribute
|
113 |
nodedata VARCHAR2(4000), -- the data for this node (e.g., |
114 |
-- for TEXT it is the content)
|
115 |
parentnodeid NUMBER(20), -- index of the parent of this node |
116 |
rootnodeid NUMBER(20), -- index of the root node of this tree |
117 |
docid VARCHAR2(250), -- index to the document id |
118 |
date_created DATE,
|
119 |
date_updated DATE,
|
120 |
nodedatanumerical NUMBER, -- the data for this node if it is a number
|
121 |
nodedatadate TIMESTAMP, -- the data for this node if it is a date |
122 |
CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid), |
123 |
CONSTRAINT xml_nodes_root_fk
|
124 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes, |
125 |
CONSTRAINT xml_nodes_parent_fk
|
126 |
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes |
127 |
); |
128 |
CREATE TRIGGER xml_nodes_before_insert |
129 |
BEFORE INSERT ON xml_nodes FOR EACH ROW |
130 |
BEGIN
|
131 |
SELECT xml_nodes_id_seq.nextval
|
132 |
INTO :new.nodeid
|
133 |
FROM dual;
|
134 |
END;
|
135 |
/ |
136 |
|
137 |
|
138 |
/*
|
139 |
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
|
140 |
*/
|
141 |
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid); |
142 |
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid); |
143 |
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename); |
144 |
CREATE INDEX xml_nodes_idx4 ON xml_nodes (docid); |
145 |
|
146 |
|
147 |
/*
|
148 |
* xml_nodes_revisions -- table to store nodes from xml_nodes which are of old revisions and deleted document
|
149 |
*/
|
150 |
|
151 |
CREATE TABLE xml_nodes_revisions ( |
152 |
nodeid NUMBER(20), -- the unique node id (pk) |
153 |
nodeindex NUMBER(10), -- order of nodes within parent |
154 |
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI, |
155 |
-- ELEMENT, ATTRIBUTE, TEXT)
|
156 |
nodename VARCHAR2(250), -- the name of an element or attribute |
157 |
nodeprefix VARCHAR2(50), -- the namespace prefix of an element |
158 |
-- or attribute
|
159 |
nodedata VARCHAR2(4000), -- the data for this node (e.g., |
160 |
-- for TEXT it is the content)
|
161 |
parentnodeid NUMBER(20), -- index of the parent of this node |
162 |
rootnodeid NUMBER(20), -- index of the root node of this tree |
163 |
docid VARCHAR2(250), -- index to the document id |
164 |
date_created DATE,
|
165 |
date_updated DATE,
|
166 |
nodedatanumerical NUMBER, -- the data for this node if it is a number
|
167 |
nodedatadate TIMESTAMP, -- the data for this node if it is a date |
168 |
CONSTRAINT xml_nodes_revisions_pk PRIMARY KEY (nodeid), |
169 |
CONSTRAINT xml_nodes_revisions_root_fk
|
170 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions, |
171 |
CONSTRAINT xml_nodes_revisions_parent_fk
|
172 |
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes_revisions |
173 |
); |
174 |
|
175 |
|
176 |
/*
|
177 |
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes_revision
|
178 |
*/
|
179 |
CREATE INDEX xml_nodes_revisions_idx1 ON xml_nodes_revisions (rootnodeid); |
180 |
CREATE INDEX xml_nodes_revisions_idx2 ON xml_nodes_revisions (parentnodeid); |
181 |
CREATE INDEX xml_nodes_revisions_idx3 ON xml_nodes_revisions (nodename); |
182 |
|
183 |
/*
|
184 |
* XML Catalog -- table to store all external sources for XML documents
|
185 |
*/
|
186 |
CREATE TABLE xml_catalog ( |
187 |
catalog_id NUMBER(20), -- the id for this catalog entry |
188 |
entry_type VARCHAR2(500), -- the type of this catalog entry |
189 |
-- (e.g., DTD, XSD, XSL)
|
190 |
source_doctype VARCHAR2(500), -- the source public_id for transforms |
191 |
target_doctype VARCHAR2(500), -- the target public_id for transforms |
192 |
public_id VARCHAR2(500), -- the unique id for this type |
193 |
system_id VARCHAR2(1000), -- the local location of the object |
194 |
CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id), |
195 |
CONSTRAINT xml_catalog_uk UNIQUE |
196 |
(entry_type, source_doctype, target_doctype, public_id) |
197 |
); |
198 |
|
199 |
CREATE SEQUENCE xml_catalog_id_seq;
|
200 |
|
201 |
CREATE TRIGGER xml_catalog_before_insert |
202 |
BEFORE INSERT ON xml_catalog FOR EACH ROW |
203 |
BEGIN
|
204 |
SELECT xml_catalog_id_seq.nextval
|
205 |
INTO :new.catalog_id
|
206 |
FROM dual;
|
207 |
END;
|
208 |
/ |
209 |
|
210 |
/*
|
211 |
* Documents -- table to store XML documents
|
212 |
*/
|
213 |
CREATE TABLE xml_documents ( |
214 |
docid VARCHAR2(250), -- the document id # |
215 |
rootnodeid NUMBER(20), -- reference to root node of the DOM |
216 |
docname VARCHAR2(100), -- usually the root element name |
217 |
doctype VARCHAR2(100), -- public id indicating document type |
218 |
user_owner VARCHAR2(100), -- the user owned the document |
219 |
user_updated VARCHAR2(100), -- the user updated the document |
220 |
server_location NUMBER(20), -- the server on which this document |
221 |
-- originates
|
222 |
rev NUMBER(10) DEFAULT 1,--the revision number of the docume |
223 |
date_created DATE,
|
224 |
date_updated DATE,
|
225 |
public_access NUMBER(1), -- flag for public access |
226 |
catalog_id NUMBER(20), -- reference to xml_catalog |
227 |
CONSTRAINT xml_documents_pk PRIMARY KEY (docid), |
228 |
CONSTRAINT xml_documents_rep_fk
|
229 |
FOREIGN KEY (server_location) REFERENCES xml_replication, |
230 |
CONSTRAINT xml_documents_root_fk
|
231 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes, |
232 |
CONSTRAINT xml_documents_catalog_fk
|
233 |
FOREIGN KEY (catalog_id) REFERENCES xml_catalog |
234 |
); |
235 |
|
236 |
/*
|
237 |
* Index of <docid,doctype> in xml_document
|
238 |
*/
|
239 |
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype); |
240 |
CREATE INDEX xml_documents_idx2 ON xml_documents (lower(user_owner)); |
241 |
CREATE INDEX xml_documents_idx3 ON xml_documents (rootnodeid); |
242 |
|
243 |
/*
|
244 |
* Revised Documents -- table to store XML documents saved after an UPDATE
|
245 |
* or DELETE
|
246 |
*/
|
247 |
CREATE TABLE xml_revisions ( |
248 |
revisionid NUMBER(20), -- the revision number we are saving |
249 |
docid VARCHAR2(250), -- the document id # |
250 |
rootnodeid NUMBER(20), -- reference to root node of the DOM |
251 |
docname VARCHAR2(100), -- usually the root element name |
252 |
doctype VARCHAR2(100), -- public id indicating document type |
253 |
user_owner VARCHAR2(100), |
254 |
user_updated VARCHAR2(100), |
255 |
server_location NUMBER(20),
|
256 |
rev NUMBER(10),
|
257 |
date_created DATE,
|
258 |
date_updated DATE,
|
259 |
public_access NUMBER(1), -- flag for public access |
260 |
catalog_id NUMBER(20), -- reference to xml_catalog |
261 |
CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid), |
262 |
CONSTRAINT xml_revisions_rep_fk
|
263 |
FOREIGN KEY (server_location) REFERENCES xml_replication, |
264 |
CONSTRAINT xml_revisions_root_fk
|
265 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions, |
266 |
CONSTRAINT xml_revisions_catalog_fk
|
267 |
FOREIGN KEY (catalog_id) REFERENCES xml_catalog |
268 |
); |
269 |
|
270 |
CREATE SEQUENCE xml_revisions_id_seq;
|
271 |
|
272 |
CREATE TRIGGER xml_revisions_before_insert |
273 |
BEFORE INSERT ON xml_revisions FOR EACH ROW |
274 |
BEGIN
|
275 |
SELECT xml_revisions_id_seq.nextval
|
276 |
INTO :new.revisionid
|
277 |
FROM dual;
|
278 |
END;
|
279 |
/ |
280 |
|
281 |
/*
|
282 |
* ACL -- table to store ACL for XML documents by principals
|
283 |
*/
|
284 |
CREATE TABLE xml_access ( |
285 |
docid VARCHAR2(250), -- the document id # |
286 |
guid VARCHAR2(2000), -- the globally unique string identifier |
287 |
accessfileid VARCHAR2(250), -- the document id # for the access file |
288 |
principal_name VARCHAR2(100), -- name of user, group, etc. |
289 |
permission NUMBER(1), -- "read", "write", "all" |
290 |
perm_type VARCHAR2(32), -- "allowed" or "denied" |
291 |
perm_order VARCHAR2(32), -- "allow first" or "deny first" |
292 |
begin_time DATE, -- the time that permission begins |
293 |
end_time DATE, -- the time that permission ends |
294 |
ticket_count NUMBER(5), -- ticket counter for that permission |
295 |
subtreeid VARCHAR2(32), -- sub tree id |
296 |
startnodeid NUMBER(20), -- start node for sub tree |
297 |
endnodeid NUMBER(20), -- end node for sub tree |
298 |
CONSTRAINT xml_access_ck CHECK (begin_time < end_time), |
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 |
nodedatadate TIMESTAMP, -- the data for this node if it is a date |
342 |
parentnodeid NUMBER(20), -- index of the parent of this node |
343 |
CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid), |
344 |
CONSTRAINT xml_path_index_docid_fk FOREIGN KEY (docid) REFERENCES xml_documents |
345 |
); |
346 |
|
347 |
|
348 |
/*
|
349 |
* create sequence an trigger
|
350 |
*/
|
351 |
CREATE SEQUENCE xml_path_index_id_seq;
|
352 |
CREATE TRIGGER xml_path_index_before_insert |
353 |
BEFORE INSERT ON xml_path_index FOR EACH ROW |
354 |
BEGIN
|
355 |
SELECT xml_path_index_id_seq.nextval
|
356 |
INTO :new.nodeid
|
357 |
FROM dual;
|
358 |
END;
|
359 |
/ |
360 |
|
361 |
|
362 |
/*
|
363 |
* Index of the path, nodedata, nodedatanumerical in xml_path_index
|
364 |
*/
|
365 |
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path); |
366 |
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata); |
367 |
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical); |
368 |
CREATE INDEX xml_path_index_idx4 ON xml_path_index (nodedatadate); |
369 |
|
370 |
|
371 |
|
372 |
|
373 |
CREATE TABLE xml_relation ( |
374 |
relationid NUMBER(20) PRIMARY KEY, -- unique id |
375 |
docid VARCHAR2(250), -- the docid of the package file |
376 |
-- that this relation came from
|
377 |
packagetype VARCHAR2(250), -- the type of the package |
378 |
subject VARCHAR2(512) NOT NULL, -- the subject of the relation |
379 |
subdoctype VARCHAR2(128), -- the doctype of the subject |
380 |
relationship VARCHAR2(128) NOT NULL,-- the relationship type |
381 |
object VARCHAR2(512) NOT NULL, -- the object of the relation |
382 |
objdoctype VARCHAR2(128), -- the doctype of the object |
383 |
CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object), |
384 |
CONSTRAINT xml_relation_docid_fk
|
385 |
FOREIGN KEY (docid) REFERENCES xml_documents |
386 |
); |
387 |
|
388 |
CREATE SEQUENCE xml_relation_id_seq;
|
389 |
|
390 |
CREATE TRIGGER xml_relation_before_insert |
391 |
BEFORE INSERT ON xml_relation FOR EACH ROW |
392 |
BEGIN
|
393 |
SELECT xml_relation_id_seq.nextval
|
394 |
INTO :new.relationid
|
395 |
FROM dual;
|
396 |
END;
|
397 |
/ |
398 |
|
399 |
/*
|
400 |
* Table used to store all document identifiers for system metadata objects
|
401 |
* similar restraints to identifier. Cannot use identifier table for this
|
402 |
* purpose because then you have to worry about whether you insert the
|
403 |
* data first or the systemMetadata first.
|
404 |
*/
|
405 |
CREATE TABLE systemMetadata ( |
406 |
guid VARCHAR2(2000), -- the globally unique string identifier |
407 |
serial_version VARCHAR2(256), --the serial version of the object |
408 |
date_uploaded DATE, -- the date/time the document was first submitted |
409 |
rights_holder VARCHAR2(250), --the user who has rights to the document, usually the first persons to upload it |
410 |
checksum VARCHAR2(512), --the checksum of the doc using the given algorithm (see below) |
411 |
checksum_algorithm VARCHAR2(250), --the algorithm used to calculate the checksum |
412 |
origin_member_node VARCHAR2(250), --the member node where the document was first uploaded |
413 |
authoritive_member_node VARCHAR2(250), --the member node that currently controls the document |
414 |
date_modified DATE, -- the last date/time that the file was changed |
415 |
submitter VARCHAR2(256), -- the user who originally submitted the doc |
416 |
object_format VARCHAR2(256), --the format of the object |
417 |
size VARCHAR2(256), --the size of the object |
418 |
replication_allowed boolean, -- replication allowed |
419 |
number_replicas NUMBER(8), -- the number of replicas allowed |
420 |
obsoletes VARCHAR2(2000), -- the identifier of the record that this replaces |
421 |
obsoleted_by VARCHAR2(2000), -- the identifier of the record that replaces this record |
422 |
CONSTRAINT systemMetadata_pk
|
423 |
PRIMARY KEY (guid) |
424 |
) |
425 |
|
426 |
CREATE TABLE systemMetadataReplicationPolicy ( |
427 |
guid VARCHAR2(2000), -- the globally unique string identifier of the object that the system metadata describes |
428 |
member_node VARCHAR(250), -- replication member node |
429 |
policy VARCHAR2(2000), -- the policy (preferred, blocked, etc...TBD) |
430 |
CONSTRAINT systemMetadataReplicationPolicy_fk
|
431 |
FOREIGN KEY (guid) REFERENCES systemMetadata |
432 |
); |
433 |
|
434 |
CREATE TABLE systemMetadataReplicationStatus ( |
435 |
guid VARCHAR2(2000), -- the globally unique string identifier of the object that the system metadata describes |
436 |
member_node VARCHAR(250), -- replication member node |
437 |
status VARCHAR(250), -- replication status |
438 |
date_verified DATE, -- the date replication was verified |
439 |
CONSTRAINT systemMetadataReplicationStatus_fk
|
440 |
FOREIGN KEY (guid) REFERENCES systemMetadata |
441 |
); |
442 |
|
443 |
/*
|
444 |
* Table used to store all document identifiers in metacat. Each identifier
|
445 |
* has a globally unique, unconstrained string, which we will refer to as a
|
446 |
* GUID, and a local metacat identifier, which consists of the docid
|
447 |
* and revision fields. Each row maps one global identifier to the local
|
448 |
* identifier (docid) used within metacat.
|
449 |
*/
|
450 |
CREATE TABLE identifier ( |
451 |
guid VARCHAR2(2000), -- the globally unique string identifier |
452 |
docid VARCHAR2(250), -- the local document id # |
453 |
rev NUMBER(8) -- the revision part of the local identifier |
454 |
); |
455 |
|
456 |
/*
|
457 |
* accesssubtree -- table to store access subtree info
|
458 |
*/
|
459 |
CREATE TABLE xml_accesssubtree ( |
460 |
docid VARCHAR2(250), -- the document id # |
461 |
rev NUMBER(10) DEFAULT 1, --the revision number of the docume |
462 |
controllevel VARCHAR2(50), -- the level it control -- document or subtree |
463 |
subtreeid VARCHAR2(250), -- the subtree id |
464 |
startnodeid NUMBER(20), -- the start node id of access subtree |
465 |
endnodeid NUMBER(20), -- the end node if of access subtree |
466 |
CONSTRAINT xml_accesssubtree_docid_fk
|
467 |
FOREIGN KEY (docid) REFERENCES xml_documents |
468 |
); |
469 |
|
470 |
/*
|
471 |
* Returnfields -- table to store combinations of returnfields requested
|
472 |
* and the number of times this table is accessed
|
473 |
*/
|
474 |
CREATE TABLE xml_returnfield ( |
475 |
returnfield_id NUMBER(20), -- the id for this returnfield entry |
476 |
returnfield_string VARCHAR2(2000), -- the returnfield string |
477 |
usage_count NUMBER(20), -- the number of times this string |
478 |
-- has been requested
|
479 |
CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id) |
480 |
); |
481 |
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string); |
482 |
|
483 |
CREATE SEQUENCE xml_returnfield_id_seq;
|
484 |
|
485 |
CREATE TRIGGER xml_returnfield_before_insert |
486 |
BEFORE INSERT ON xml_returnfield FOR EACH ROW |
487 |
BEGIN
|
488 |
SELECT xml_returnfield_id_seq.nextval
|
489 |
INTO :new.returnfield_id
|
490 |
FROM dual;
|
491 |
END;
|
492 |
/ |
493 |
|
494 |
/*
|
495 |
* Queryresults -- table to store queryresults for a given docid
|
496 |
* and returnfield_id
|
497 |
*/
|
498 |
CREATE TABLE xml_queryresult( |
499 |
queryresult_id NUMBER(20), -- id for this entry |
500 |
returnfield_id NUMBER(20), -- id for the returnfield corresponding to this entry |
501 |
docid VARCHAR2(250), -- docid of the document |
502 |
queryresult_string VARCHAR2(4000), -- resultant text generated for this docid and given |
503 |
-- returnfield
|
504 |
CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id), |
505 |
CONSTRAINT xml_queryresult_searchid_fk
|
506 |
FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield |
507 |
); |
508 |
|
509 |
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid); |
510 |
|
511 |
CREATE SEQUENCE xml_queryresult_id_seq;
|
512 |
|
513 |
CREATE TRIGGER xml_queryresult_before_insert |
514 |
BEFORE INSERT ON xml_queryresult FOR EACH ROW |
515 |
BEGIN
|
516 |
SELECT xml_queryresult_id_seq.nextval
|
517 |
INTO :new.queryresult_id
|
518 |
FROM dual;
|
519 |
END;
|
520 |
/ |
521 |
|
522 |
|
523 |
|
524 |
|
525 |
/*
|
526 |
* Logging -- table to store metadata and data access log
|
527 |
*/
|
528 |
CREATE TABLE access_log ( |
529 |
entryid NUMBER(20), -- the identifier for the log event |
530 |
ip_address VARCHAR2(512), -- the ip address inititiating the event |
531 |
user_agent VARCHAR2(512), -- the user agent for the request |
532 |
principal VARCHAR2(512), -- the user initiiating the event |
533 |
docid VARCHAR2(250), -- the document id # |
534 |
event VARCHAR2(512), -- the code symbolizing the event type |
535 |
date_logged DATE, -- the datetime on which the event occurred |
536 |
CONSTRAINT access_log_pk PRIMARY KEY (entryid) |
537 |
); |
538 |
|
539 |
CREATE SEQUENCE access_log_id_seq;
|
540 |
CREATE TRIGGER access_log_before_insert |
541 |
BEFORE INSERT ON access_log FOR EACH ROW |
542 |
BEGIN
|
543 |
SELECT access_log_id_seq.nextval
|
544 |
INTO :new.entryid
|
545 |
FROM dual;
|
546 |
END;
|
547 |
/ |
548 |
|
549 |
/*
|
550 |
* harvest_site_schedule -- table to store harvest sites and schedule info
|
551 |
*/
|
552 |
CREATE TABLE harvest_site_schedule ( |
553 |
site_schedule_id NUMBER, -- unique id
|
554 |
documentlisturl VARCHAR2(255), -- URL of the site harvest document list |
555 |
ldapdn VARCHAR2(255), -- LDAP distinguished name for site account |
556 |
datenextharvest DATE, -- scheduled date of next harvest |
557 |
datelastharvest DATE, -- recorded date of last harvest |
558 |
updatefrequency NUMBER, -- the harvest update frequency
|
559 |
unit VARCHAR2(50), -- update unit -- days weeks or months |
560 |
contact_email VARCHAR2(50), -- email address of the site contact person |
561 |
ldappwd VARCHAR2(20), -- LDAP password for site account |
562 |
CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id) |
563 |
); |
564 |
|
565 |
/*
|
566 |
* harvest_log -- table to log entries for harvest operations
|
567 |
*/
|
568 |
CREATE TABLE harvest_log ( |
569 |
harvest_log_id NUMBER, -- unique id
|
570 |
harvest_date DATE, -- date of the current harvest |
571 |
status NUMBER, -- non-zero indicates an error status
|
572 |
message VARCHAR2(1000), -- text message for this log entry |
573 |
harvest_operation_code VARCHAR2(30), -- the type of harvest operation |
574 |
site_schedule_id NUMBER, -- site schedule id, or 0 if no site
|
575 |
CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id) |
576 |
); |
577 |
|
578 |
/*
|
579 |
* harvest_detail_log -- table to log detailed info about documents that
|
580 |
* generated errors during the harvest
|
581 |
*/
|
582 |
CREATE TABLE harvest_detail_log ( |
583 |
detail_log_id NUMBER, -- unique id
|
584 |
harvest_log_id NUMBER, -- ponter to the related log entry
|
585 |
scope VARCHAR2(50), -- document scope |
586 |
identifier NUMBER, -- document identifier
|
587 |
revision NUMBER, -- document revision
|
588 |
document_url VARCHAR2(255), -- document URL |
589 |
error_message VARCHAR2(1000), -- text error message |
590 |
document_type VARCHAR2(100), -- document type |
591 |
CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id), |
592 |
CONSTRAINT harvest_detail_log_fk
|
593 |
FOREIGN KEY (harvest_log_id) REFERENCES harvest_log |
594 |
); |
595 |
|
596 |
/*
|
597 |
* db_version -- table to store the version history of this database
|
598 |
*/
|
599 |
CREATE TABLE db_version ( |
600 |
db_version_id NUMBER(20), -- the identifier for the version |
601 |
version VARCHAR(250), -- the version number |
602 |
status NUMBER(20), -- status of the version |
603 |
date_created DATE, -- the datetime on which the version was created |
604 |
CONSTRAINT db_version_pk PRIMARY KEY (db_version_id) |
605 |
); |
606 |
|
607 |
CREATE SEQUENCE db_version_id_seq;
|
608 |
CREATE TRIGGER db_version_before_insert |
609 |
BEFORE INSERT ON db_version FOR EACH ROW |
610 |
BEGIN
|
611 |
SELECT db_version_id_seq.nextval
|
612 |
INTO :new.db_version_id
|
613 |
FROM dual;
|
614 |
END;
|
615 |
/ |
616 |
|
617 |
/*
|
618 |
* scheduled_job -- table to store scheduled jobs
|
619 |
*/
|
620 |
CREATE TABLE scheduled_job ( |
621 |
id NUMBER(20) NOT NULL default nextval('scheduled_job_id_seq'), |
622 |
date_created TIMESTAMP NOT NULL, |
623 |
date_updated TIMESTAMP NOT NULL, |
624 |
status VARCHAR2(64) NOT NULL, |
625 |
name VARCHAR2(512) NOT NULL, |
626 |
trigger_name VARCHAR2(512) NOT NULL, |
627 |
group_name VARCHAR2(512) NOT NULL, |
628 |
class_name VARCHAR2(1024) NOT NULL, |
629 |
start_time TIMESTAMP NOT NULL, |
630 |
interval_value NUMBER NOT NULL, |
631 |
interval_unit VARCHAR2(8) NOT NULL, |
632 |
CONSTRAINT scheduled_job_pk PRIMARY KEY (id), |
633 |
CONSTRAINT scheduled_job_uk UNIQUE (name) |
634 |
); |
635 |
|
636 |
CREATE SEQUENCE scheduled_job_id_seq;
|
637 |
CREATE TRIGGER scheduled_job_before_insert |
638 |
BEFORE INSERT ON scheduled_job FOR EACH ROW |
639 |
BEGIN
|
640 |
SELECT scheduled_job_id_seq.nextval
|
641 |
INTO :new.id
|
642 |
FROM dual;
|
643 |
END;
|
644 |
/ |
645 |
|
646 |
/*
|
647 |
* scheduled_job_params -- table to store scheduled job parameters
|
648 |
*/
|
649 |
CREATE TABLE scheduled_job_params ( |
650 |
id NUMBER(20) NOT NULL default nextval('scheduled_job_params_id_seq'), |
651 |
date_created TIMESTAMP NOT NULL, |
652 |
date_updated TIMESTAMP NOT NULL, |
653 |
status VARCHAR2(64) NOT NULL, |
654 |
job_id NUMBER(20) NOT NULL, |
655 |
key VARCHAR2(64) NOT NULL, |
656 |
value VARCHAR2(1024) NOT NULL, |
657 |
CONSTRAINT scheduled_job_params_pk PRIMARY KEY (id), |
658 |
CONSTRAINT scheduled_job_params_fk
|
659 |
FOREIGN KEY (job_id) REFERENCES scheduled_job(id) |
660 |
); |
661 |
|
662 |
CREATE SEQUENCE scheduled_job_params_id_seq;
|
663 |
CREATE TRIGGER scheduled_job_params_before_insert |
664 |
BEFORE INSERT ON scheduled_job_params FOR EACH ROW |
665 |
BEGIN
|
666 |
SELECT scheduled_job_id_params_seq.nextval
|
667 |
INTO :new.id
|
668 |
FROM dual;
|
669 |
END;
|
670 |
/ |
671 |
|