metacat / src / xmltables-postgres.sql @ 8013
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: 2013-06-25 16:42:40 -0700 (Tue, 25 Jun 2013) $'
|
8 |
* '$Revision: 7830 $'
|
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 |
* this is sql script does the same as the sql script named
|
27 |
* xmltables.sql except that this script is to be use to
|
28 |
* create the database tables on a Postgresql backend rather
|
29 |
* than an Oracle Backend
|
30 |
*/
|
31 |
|
32 |
/*
|
33 |
* Replication -- table to store servers that metacat is replicated to
|
34 |
*/
|
35 |
CREATE SEQUENCE xml_replication_id_seq;
|
36 |
CREATE TABLE xml_replication ( |
37 |
serverid INT8 default nextval('xml_replication_id_seq'), |
38 |
server VARCHAR(512), |
39 |
last_checked DATE,
|
40 |
replicate INT8, |
41 |
datareplicate INT8, |
42 |
hub INT8, |
43 |
CONSTRAINT xml_replication_pk PRIMARY KEY (serverid) |
44 |
); |
45 |
|
46 |
INSERT INTO xml_replication (server, replicate, datareplicate, hub) VALUES ('localhost', '0', '0', '0'); |
47 |
|
48 |
|
49 |
/*
|
50 |
* Nodes -- table to store XML Nodes (both elements and attributes)
|
51 |
*/
|
52 |
CREATE SEQUENCE xml_nodes_id_seq;
|
53 |
CREATE TABLE xml_nodes ( |
54 |
nodeid INT8 default nextval('xml_nodes_id_seq'), |
55 |
-- the unique node id (pk)
|
56 |
nodeindex INT8, -- order of nodes within parent
|
57 |
nodetype VARCHAR(20), -- type (DOCUMENT, COMMENT, PI, |
58 |
-- ELEMENT, ATTRIBUTE, TEXT)
|
59 |
nodename VARCHAR(250), -- the name of an element or attribute |
60 |
nodeprefix VARCHAR(50), -- the namespace prefix of the node |
61 |
nodedata TEXT, -- the data for this node (e.g., |
62 |
-- for TEXT it is the content)
|
63 |
parentnodeid INT8, -- index of the parent of this node
|
64 |
rootnodeid INT8, -- index of the root node of this tree
|
65 |
docid VARCHAR(250), -- index to the document id |
66 |
date_created DATE,
|
67 |
date_updated DATE,
|
68 |
nodedatanumerical FLOAT8, -- the data for this node if it is a number
|
69 |
nodedatadate TIMESTAMP, -- the data for this node if it is a date |
70 |
CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid), |
71 |
CONSTRAINT xml_nodes_root_fk
|
72 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes, |
73 |
CONSTRAINT xml_nodes_parent_fk
|
74 |
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes |
75 |
); |
76 |
/*
|
77 |
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
|
78 |
*/
|
79 |
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid); |
80 |
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid); |
81 |
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename); |
82 |
CREATE INDEX xml_nodes_idx4 ON xml_nodes (docid); |
83 |
|
84 |
|
85 |
/*
|
86 |
* Table for storing the nodes for the old revisions of the document and the deleted documents
|
87 |
*/
|
88 |
CREATE TABLE xml_nodes_revisions ( |
89 |
nodeid INT8, -- the unique node id (pk)
|
90 |
nodeindex INT8, -- order of nodes within parent
|
91 |
nodetype VARCHAR(20), -- type (DOCUMENT, COMMENT, PI, |
92 |
-- ELEMENT, ATTRIBUTE, TEXT)
|
93 |
nodename VARCHAR(250), -- the name of an element or attribute |
94 |
nodeprefix VARCHAR(50), -- the namespace prefix of the node |
95 |
nodedata TEXT, -- the data for this node (e.g., |
96 |
-- for TEXT it is the content)
|
97 |
parentnodeid INT8, -- index of the parent of this node
|
98 |
rootnodeid INT8, -- index of the root node of this tree
|
99 |
docid VARCHAR(250), -- index to the document id |
100 |
date_created DATE,
|
101 |
date_updated DATE,
|
102 |
nodedatanumerical FLOAT8, -- the data for this node if it is a number
|
103 |
nodedatadate TIMESTAMP, -- the data for this node if it is a date |
104 |
CONSTRAINT xml_nodes_revisions_pk PRIMARY KEY (nodeid), |
105 |
CONSTRAINT xml_nodes_revisions_root_fk
|
106 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions, |
107 |
CONSTRAINT xml_nodes_revisions_parent_fk
|
108 |
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes_revisions |
109 |
); |
110 |
|
111 |
/*
|
112 |
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes_revisions
|
113 |
*/
|
114 |
CREATE INDEX xml_nodes_revisions_idx1 ON xml_nodes_revisions (rootnodeid); |
115 |
CREATE INDEX xml_nodes_revisions_idx2 ON xml_nodes_revisions (parentnodeid); |
116 |
CREATE INDEX xml_nodes_revisions_idx3 ON xml_nodes_revisions (nodename); |
117 |
|
118 |
|
119 |
|
120 |
/*
|
121 |
* XML Catalog -- table to store all external sources for XML documents
|
122 |
*/
|
123 |
CREATE SEQUENCE xml_catalog_id_seq;
|
124 |
CREATE TABLE xml_catalog ( |
125 |
catalog_id INT8 default nextval('xml_catalog_id_seq'), |
126 |
-- the id for this catalog entry
|
127 |
entry_type VARCHAR(500), -- the type of this catalog entry |
128 |
-- (e.g., DTD, XSD, XSL)
|
129 |
source_doctype VARCHAR(500), -- the source public_id for transforms |
130 |
target_doctype VARCHAR(500), -- the target public_id for transforms |
131 |
public_id VARCHAR(500), -- the unique id for this type |
132 |
system_id VARCHAR(1000), -- the local location of the object |
133 |
CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id), |
134 |
CONSTRAINT xml_catalog_uk UNIQUE |
135 |
(entry_type, source_doctype, target_doctype, public_id) |
136 |
); |
137 |
|
138 |
/*
|
139 |
* Sequence to get uniqueID for Accession #
|
140 |
*/
|
141 |
CREATE SEQUENCE xml_documents_id_seq;
|
142 |
/*
|
143 |
* Documents -- table to store XML documents
|
144 |
*/
|
145 |
CREATE TABLE xml_documents ( |
146 |
docid VARCHAR(250), -- the document id # |
147 |
rootnodeid INT8, -- reference to root node of the DOM
|
148 |
docname VARCHAR(100), -- usually the root element name |
149 |
doctype VARCHAR(100), -- public id indicating document type |
150 |
user_owner VARCHAR(100), -- the user owned the document |
151 |
user_updated VARCHAR(100), -- the user updated the document |
152 |
server_location INT8, -- the server on which this document resides
|
153 |
rev INT8 default 1, -- the revision number of the document |
154 |
date_created DATE,
|
155 |
date_updated DATE,
|
156 |
public_access INT8, -- flag for public access
|
157 |
catalog_id INT8, -- reference to xml_catalog
|
158 |
CONSTRAINT xml_documents_pk PRIMARY KEY (docid), |
159 |
CONSTRAINT xml_documents_rep_fk
|
160 |
FOREIGN KEY (server_location) REFERENCES xml_replication, |
161 |
CONSTRAINT xml_documents_root_fk
|
162 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes, |
163 |
CONSTRAINT xml_documents_catalog_fk
|
164 |
FOREIGN KEY (catalog_id) REFERENCES xml_catalog |
165 |
); |
166 |
|
167 |
/*
|
168 |
* Index of <docid,doctype> in xml_document
|
169 |
*/
|
170 |
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype); |
171 |
CREATE INDEX xml_documents_idx2 ON xml_documents (lower(user_owner)); |
172 |
CREATE INDEX xml_documents_idx3 ON xml_documents (rootnodeid); |
173 |
CREATE INDEX xml_documents_idx5 ON xml_documents (docid, rev); |
174 |
|
175 |
/*
|
176 |
* Revised Documents -- table to store XML documents saved after an UPDATE
|
177 |
* or DELETE
|
178 |
*/
|
179 |
CREATE SEQUENCE xml_revisions_id_seq;
|
180 |
CREATE TABLE xml_revisions ( |
181 |
revisionid INT8 default nextval('xml_revisions_id_seq'), |
182 |
-- the revision number we are saving
|
183 |
docid VARCHAR(250), -- the document id # |
184 |
rootnodeid INT8, -- reference to root node of the DOM
|
185 |
docname VARCHAR(100), -- usually the root element name |
186 |
doctype VARCHAR(100), -- public id indicating document type |
187 |
user_owner VARCHAR(100), |
188 |
user_updated VARCHAR(100), |
189 |
server_location INT8, |
190 |
rev INT8, |
191 |
date_created DATE,
|
192 |
date_updated DATE,
|
193 |
public_access INT8, -- flag for public access
|
194 |
catalog_id INT8, -- reference to xml_catalog
|
195 |
CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid), |
196 |
CONSTRAINT xml_revisions_rep_fk
|
197 |
FOREIGN KEY (server_location) REFERENCES xml_replication, |
198 |
CONSTRAINT xml_revisions_root_fk
|
199 |
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions, |
200 |
CONSTRAINT xml_revisions_catalog_fk
|
201 |
FOREIGN KEY (catalog_id) REFERENCES xml_catalog |
202 |
); |
203 |
|
204 |
CREATE INDEX xml_revisions_idx1 ON xml_revisions (docid); |
205 |
|
206 |
/*
|
207 |
* ACL -- table to store ACL for XML documents by principals
|
208 |
*/
|
209 |
CREATE TABLE xml_access ( |
210 |
guid text, -- foreign key to system metadata |
211 |
accessfileid text, -- the id for the access file |
212 |
principal_name VARCHAR(100), -- name of user, group, etc. |
213 |
permission INT8, -- "read", "write", "all"
|
214 |
perm_type VARCHAR(32), -- "allowed" or "denied" |
215 |
perm_order VARCHAR(32), -- "allow first" or "deny first" |
216 |
begin_time DATE, -- the time that permission begins |
217 |
end_time DATE, -- the time that permission ends |
218 |
ticket_count INT8, -- ticket counter for that permission
|
219 |
subtreeid VARCHAR(32), |
220 |
startnodeid INT8, |
221 |
endnodeid INT8, |
222 |
CONSTRAINT xml_access_ck CHECK (begin_time < end_time) |
223 |
); |
224 |
CREATE INDEX xml_access_idx1 ON xml_access (lower(principal_name)); |
225 |
CREATE INDEX xml_access_idx2 ON xml_access (permission); |
226 |
CREATE INDEX xml_access_idx3 ON xml_access (perm_type); |
227 |
CREATE INDEX xml_access_idx4 ON xml_access (perm_order); |
228 |
CREATE INDEX xml_access_idx5 ON xml_access (subtreeid); |
229 |
CREATE INDEX xml_access_idx6 on xml_access(guid); |
230 |
/*
|
231 |
* ALTER TABLE xml_access ADD COLUMN guid text;
|
232 |
*/
|
233 |
|
234 |
/*
|
235 |
* Index of Nodes -- table to store precomputed paths through tree for
|
236 |
* quick searching in structured searches
|
237 |
*/
|
238 |
CREATE TABLE xml_index ( |
239 |
nodeid INT8, -- the unique node id
|
240 |
path TEXT, -- precomputed path through tree |
241 |
docid VARCHAR(250), -- index to the document id |
242 |
doctype VARCHAR(100), -- public id indicating document type |
243 |
parentnodeid INT8, -- id of the parent of the node represented
|
244 |
-- by this row
|
245 |
CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path), |
246 |
CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes, |
247 |
CONSTRAINT xml_index_docid_fk
|
248 |
FOREIGN KEY (docid) REFERENCES xml_documents |
249 |
); |
250 |
|
251 |
/*
|
252 |
* Index of the paths in xml_index
|
253 |
*/
|
254 |
CREATE INDEX xml_index_idx1 ON xml_index (path); |
255 |
CREATE INDEX xml_index_idx2 ON xml_index (docid); |
256 |
CREATE INDEX xml_index_idx3 ON xml_index (nodeid); |
257 |
|
258 |
CREATE SEQUENCE xml_relation_id_seq;
|
259 |
CREATE TABLE xml_relation ( |
260 |
relationid INT8 default nextval('xml_relation_id_seq') PRIMARY KEY, |
261 |
-- unique id
|
262 |
docid VARCHAR(250) , -- the docid of the package file |
263 |
-- that this relation came from
|
264 |
packagetype VARCHAR(250), -- the type of the package |
265 |
subject VARCHAR(512) NOT NULL, -- the subject of the relation |
266 |
subdoctype VARCHAR(128), -- the doctype of the subject |
267 |
relationship VARCHAR(128) NOT NULL,-- the relationship type |
268 |
object VARCHAR(512) NOT NULL, -- the object of the relation |
269 |
objdoctype VARCHAR(128), -- the doctype of the object |
270 |
CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object), |
271 |
CONSTRAINT xml_relation_docid_fk
|
272 |
FOREIGN KEY (docid) REFERENCES xml_documents |
273 |
); |
274 |
|
275 |
/*
|
276 |
* Table used to store all document identifiers in metacat. Each identifier
|
277 |
* has a globally unique, unconstrained string, which we will refer to as a
|
278 |
* GUID, and a local metacat identifier, which consists of the docid
|
279 |
* and revision fields. Each row maps one global identifier to the local
|
280 |
* identifier (docid) used within metacat.
|
281 |
*/
|
282 |
CREATE TABLE identifier ( |
283 |
guid text, -- the globally unique string identifier |
284 |
docid VARCHAR(250), -- the local document id # |
285 |
rev INT8, -- the revision part of the local identifier
|
286 |
CONSTRAINT identifier_pk PRIMARY KEY (guid) |
287 |
); |
288 |
CREATE INDEX identifier_guid on identifier(guid); |
289 |
CREATE INDEX identifier_docid on identifier(docid); |
290 |
CREATE INDEX identifier_rev on identifier(rev); |
291 |
CREATE INDEX identifier_docid_rev on identifier(docid, rev); |
292 |
|
293 |
/*
|
294 |
* Table used to store all document identifiers for system metadata objects
|
295 |
* similar restraints to identifier. Cannot use identifier table for this
|
296 |
* purpose because then you have to worry about whether you insert the
|
297 |
* data first or the systemMetadata first.
|
298 |
*/
|
299 |
CREATE TABLE systemMetadata ( |
300 |
guid text, -- the globally unique string identifier of the object that the system metadata describes |
301 |
serial_version VARCHAR(256), --the serial version of the object |
302 |
date_uploaded TIMESTAMP, -- the date/time the document was first submitted |
303 |
rights_holder VARCHAR(250), --the user who has rights to the document, usually the first persons to upload it |
304 |
checksum VARCHAR(512), --the checksum of the doc using the given algorithm (see below) |
305 |
checksum_algorithm VARCHAR(250), --the algorithm used to calculate the checksum |
306 |
origin_member_node VARCHAR(250), --the member node where the document was first uploaded |
307 |
authoritive_member_node VARCHAR(250), --the member node that currently controls the document |
308 |
date_modified TIMESTAMP, -- the last date/time that the file was changed |
309 |
submitter VARCHAR(256), -- the user who originally submitted the doc |
310 |
object_format VARCHAR(256), --the format of the object |
311 |
size VARCHAR(256), --the size of the object |
312 |
archived boolean, -- specifies whether this an archived object |
313 |
replication_allowed boolean, -- replication allowed |
314 |
number_replicas INT8, -- the number of replicas allowed
|
315 |
obsoletes text, -- the identifier that this record obsoletes |
316 |
obsoleted_by text, -- the identifier of the record that replaces this record |
317 |
CONSTRAINT systemMetadata_pk PRIMARY KEY (guid) |
318 |
); |
319 |
/*
|
320 |
* For devs to remove docid, rev
|
321 |
* ALTER TABLE systemMetadata DROP COLUMN docid;
|
322 |
* ALTER TABLE systemMetadata DROP COLUMN rev;
|
323 |
* ALTER TABLE systemMetadata ADD COLUMN replication_allowed boolean;
|
324 |
* ALTER TABLE systemMetadata ADD COLUMN number_replicas INT8;
|
325 |
*/
|
326 |
|
327 |
|
328 |
CREATE TABLE smReplicationPolicy ( |
329 |
guid text, -- the globally unique string identifier of the object that the system metadata describes |
330 |
member_node VARCHAR(250), -- replication member node |
331 |
policy text, -- the policy (preferred, blocked, etc...TBD) |
332 |
CONSTRAINT smReplicationPolicy_fk
|
333 |
FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE |
334 |
); |
335 |
|
336 |
CREATE TABLE smReplicationStatus ( |
337 |
guid text, -- the globally unique string identifier of the object that the system metadata describes |
338 |
member_node VARCHAR(250), -- replication member node |
339 |
status VARCHAR(250), -- replication status |
340 |
date_verified TIMESTAMP, -- the date replication was verified |
341 |
CONSTRAINT smReplicationStatus_fk
|
342 |
FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE |
343 |
); |
344 |
|
345 |
/*
|
346 |
* accesssubtree -- table to store access subtree info
|
347 |
*/
|
348 |
CREATE TABLE xml_accesssubtree ( |
349 |
docid VARCHAR(250), -- the document id # |
350 |
rev INT8 default 1, --the revision number of the docume |
351 |
controllevel VARCHAR(50), -- the level it control -- document or subtree |
352 |
subtreeid VARCHAR(250), -- the subtree id |
353 |
startnodeid INT8, -- the start node id of access subtree
|
354 |
endnodeid INT8, -- the end node if of access subtree
|
355 |
CONSTRAINT xml_accesssubtree_docid_fk
|
356 |
FOREIGN KEY (docid) REFERENCES xml_documents |
357 |
); |
358 |
|
359 |
/*
|
360 |
* Returnfields -- table to store combinations of returnfields requested
|
361 |
* and the number of times this table is accessed
|
362 |
*/
|
363 |
CREATE SEQUENCE xml_returnfield_id_seq;
|
364 |
CREATE TABLE xml_returnfield ( |
365 |
returnfield_id INT8 default nextval('xml_returnfield_id_seq'), -- the id for this returnfield entry |
366 |
returnfield_string VARCHAR(2000), -- the returnfield string |
367 |
usage_count INT8, -- the number of times this string has been requested
|
368 |
CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id) |
369 |
); |
370 |
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string); |
371 |
|
372 |
/*
|
373 |
* Queryresults -- table to store queryresults for a given docid
|
374 |
* and returnfield_id
|
375 |
*/
|
376 |
CREATE SEQUENCE xml_queryresult_id_seq;
|
377 |
CREATE TABLE xml_queryresult( |
378 |
queryresult_id INT8 default nextval('xml_queryresult_id_seq'), -- id for this entry |
379 |
returnfield_id INT8, -- id for the returnfield corresponding to this entry
|
380 |
docid VARCHAR(250), -- docid of the document |
381 |
queryresult_string TEXT, -- resultant text generated for this docid and given |
382 |
-- returnfield
|
383 |
CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id), |
384 |
CONSTRAINT xml_queryresult_searchid_fk
|
385 |
FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield |
386 |
); |
387 |
|
388 |
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid); |
389 |
|
390 |
/*
|
391 |
* Logging -- table to store metadata and data access log
|
392 |
*/
|
393 |
CREATE SEQUENCE access_log_id_seq;
|
394 |
CREATE TABLE access_log ( |
395 |
entryid INT8 default nextval ('access_log_id_seq'), -- the identifier for the log event |
396 |
ip_address VARCHAR(512), -- the ip address inititiating the event |
397 |
user_agent VARCHAR(512), -- the user agent for the request |
398 |
principal VARCHAR(512), -- the user initiating the event |
399 |
docid VARCHAR(250), -- the document id # |
400 |
event VARCHAR(512), -- the code symbolizing the event type |
401 |
date_logged TIMESTAMP, -- the datetime on which the event occurred |
402 |
CONSTRAINT access_log_pk PRIMARY KEY (entryid) |
403 |
); |
404 |
|
405 |
/*
|
406 |
* the index_event table for solr-based indexing
|
407 |
*/
|
408 |
CREATE TABLE index_event ( |
409 |
guid text,
|
410 |
event_action VARCHAR(250), |
411 |
description text,
|
412 |
event_date TIMESTAMP
|
413 |
); |
414 |
|
415 |
/*
|
416 |
* Table for indexing the paths specified the administrator in metacat.properties
|
417 |
*/
|
418 |
|
419 |
CREATE SEQUENCE xml_path_index_id_seq;
|
420 |
CREATE TABLE xml_path_index ( |
421 |
nodeid INT8 default nextval('xml_path_index_id_seq'), |
422 |
docid VARCHAR(250), -- the document id |
423 |
path TEXT, -- precomputed path through tree |
424 |
nodedata TEXT, -- the data for this node (e.g., |
425 |
-- for TEXT it is the content)
|
426 |
nodedatanumerical FLOAT8, -- the data for this node if it is a number
|
427 |
nodedatadate TIMESTAMP, -- the data for this node if it is a date |
428 |
parentnodeid INT8, -- id of the parent of the node represented
|
429 |
-- by this row
|
430 |
CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid), |
431 |
CONSTRAINT xml_path_index_docid_fk
|
432 |
FOREIGN KEY (docid) REFERENCES xml_documents |
433 |
); |
434 |
|
435 |
/*
|
436 |
* Indexes of path, nodedata and nodedatanumerical in xml_path_index
|
437 |
*/
|
438 |
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path); |
439 |
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata); |
440 |
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical); |
441 |
CREATE INDEX xml_path_index_idx4 ON xml_path_index (upper(nodedata)); |
442 |
CREATE INDEX xml_path_index_idx5 ON xml_path_index (nodedatadate); |
443 |
CREATE INDEX xml_path_index_idx6 ON xml_path_index (docid); |
444 |
|
445 |
/*
|
446 |
* harvest_site_schedule -- table to store harvest sites and schedule info
|
447 |
*/
|
448 |
CREATE TABLE harvest_site_schedule ( |
449 |
site_schedule_id INT8, -- unique id
|
450 |
documentlisturl VARCHAR(255), -- URL of the site harvest document list |
451 |
ldapdn VARCHAR(255), -- LDAP distinguished name for site account |
452 |
datenextharvest DATE, -- scheduled date of next harvest |
453 |
datelastharvest DATE, -- recorded date of last harvest |
454 |
updatefrequency INT8, -- the harvest update frequency
|
455 |
unit VARCHAR(50), -- update unit -- days weeks or months |
456 |
contact_email VARCHAR(50), -- email address of the site contact person |
457 |
ldappwd VARCHAR(20), -- LDAP password for site account |
458 |
CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id) |
459 |
); |
460 |
|
461 |
/*
|
462 |
* harvest_log -- table to log entries for harvest operations
|
463 |
*/
|
464 |
CREATE TABLE harvest_log ( |
465 |
harvest_log_id INT8, -- unique id
|
466 |
harvest_date DATE, -- date of the current harvest |
467 |
status INT8, -- non-zero indicates an error status
|
468 |
message VARCHAR(1000), -- text message for this log entry |
469 |
harvest_operation_code VARCHAR(30), -- the type of harvest operation |
470 |
site_schedule_id INT8, -- site schedule id, or 0 if no site
|
471 |
CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id) |
472 |
); |
473 |
|
474 |
/*
|
475 |
* harvest_detail_log -- table to log detailed info about documents that
|
476 |
* generated errors during the harvest
|
477 |
*/
|
478 |
CREATE TABLE harvest_detail_log ( |
479 |
detail_log_id INT8, -- unique id
|
480 |
harvest_log_id INT8, -- ponter to the related log entry
|
481 |
scope VARCHAR(50), -- document scope |
482 |
identifier INT8, -- document identifier
|
483 |
revision INT8, -- document revision
|
484 |
document_url VARCHAR(255), -- document URL |
485 |
error_message VARCHAR(1000), -- text error message |
486 |
document_type VARCHAR(100), -- document type |
487 |
CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id), |
488 |
CONSTRAINT harvest_detail_log_fk
|
489 |
FOREIGN KEY (harvest_log_id) REFERENCES harvest_log |
490 |
); |
491 |
|
492 |
/*
|
493 |
* db_version -- table to store the version history of this database
|
494 |
*/
|
495 |
CREATE SEQUENCE db_version_id_seq;
|
496 |
CREATE TABLE db_version ( |
497 |
db_version_id INT8 default nextval ('db_version_id_seq'), -- the identifier for the version |
498 |
version VARCHAR(250), -- the version number |
499 |
status INT8, -- status of the version
|
500 |
date_created TIMESTAMP, -- the datetime on which the version was created |
501 |
CONSTRAINT db_version_pk PRIMARY KEY (db_version_id) |
502 |
); |
503 |
|
504 |
/*
|
505 |
* scheduled_job -- table to store scheduled jobs
|
506 |
*/
|
507 |
CREATE SEQUENCE scheduled_job_id_seq;
|
508 |
CREATE TABLE scheduled_job ( |
509 |
id INT8 NOT NULL default nextval('scheduled_job_id_seq'), |
510 |
date_created TIMESTAMP NOT NULL, |
511 |
date_updated TIMESTAMP NOT NULL, |
512 |
status VARCHAR(64) NOT NULL, |
513 |
name VARCHAR(512) NOT NULL, |
514 |
trigger_name VARCHAR(512) NOT NULL, |
515 |
group_name VARCHAR(512) NOT NULL, |
516 |
class_name VARCHAR(1024) NOT NULL, |
517 |
start_time TIMESTAMP NOT NULL, |
518 |
end_time TIMESTAMP,
|
519 |
interval_value INT NOT NULL, |
520 |
interval_unit VARCHAR(8) NOT NULL, |
521 |
CONSTRAINT scheduled_job_pk PRIMARY KEY (id), |
522 |
CONSTRAINT scheduled_job_uk UNIQUE (name) |
523 |
); |
524 |
|
525 |
/*
|
526 |
* scheduled_job_params -- table to store scheduled jobs
|
527 |
*/
|
528 |
CREATE SEQUENCE scheduled_job_params_id_seq;
|
529 |
CREATE TABLE scheduled_job_params ( |
530 |
id INT8 NOT NULL default nextval('scheduled_job_params_id_seq'), |
531 |
date_created TIMESTAMP NOT NULL, |
532 |
date_updated TIMESTAMP NOT NULL, |
533 |
status VARCHAR(64) NOT NULL, |
534 |
job_id INT8 NOT NULL, |
535 |
key VARCHAR(64) NOT NULL, |
536 |
value VARCHAR(1024) NOT NULL, |
537 |
CONSTRAINT scheduled_job_params_pk PRIMARY KEY (id), |
538 |
CONSTRAINT scheduled_job_params_fk
|
539 |
FOREIGN KEY (job_id) REFERENCES scheduled_job(id) |
540 |
); |