Project

General

Profile

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-10-18 12:16:44 -0700 (Fri, 18 Oct 2013) $'
8
 * '$Revision: 8335 $'
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 it is a number
120
	nodedatadate TIMESTAMP,       -- the data for this node if it is a date
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 it is a number
166
        nodedatadate TIMESTAMP,       -- the data for this node if it is a date
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
CREATE INDEX xml_documents_idx5 ON xml_documents (docid, rev);
242

    
243

    
244
/*
245
 * Revised Documents -- table to store XML documents saved after an UPDATE
246
 *                    or DELETE
247
 */
248
CREATE TABLE xml_revisions (
249
	revisionid	NUMBER(20),	-- the revision number we are saving
250
	docid		VARCHAR2(250),	-- the document id #
251
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
252
	docname		VARCHAR2(100),	-- usually the root element name
253
	doctype		VARCHAR2(100),	-- public id indicating document type
254
	user_owner	VARCHAR2(100),
255
	user_updated	VARCHAR2(100),
256
	server_location NUMBER(20),
257
	rev		NUMBER(10),
258
	date_created	DATE,
259
	date_updated	DATE,
260
	public_access	NUMBER(1),	-- flag for public access
261
        catalog_id      NUMBER(20),	-- reference to xml_catalog
262
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
263
   CONSTRAINT xml_revisions_rep_fk
264
		FOREIGN KEY (server_location) REFERENCES xml_replication,
265
   CONSTRAINT xml_revisions_root_fk
266
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions,
267
   CONSTRAINT xml_revisions_catalog_fk
268
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
269
);
270

    
271
CREATE SEQUENCE xml_revisions_id_seq;
272

    
273
CREATE TRIGGER xml_revisions_before_insert
274
BEFORE INSERT ON xml_revisions FOR EACH ROW
275
BEGIN
276
  SELECT xml_revisions_id_seq.nextval
277
    INTO :new.revisionid
278
    FROM dual;
279
END;
280
/
281

    
282
/*
283
 * ACL -- table to store ACL for XML documents by principals
284
 */
285
CREATE TABLE xml_access (
286
	guid   VARCHAR2(2000),    -- the globally unique string identifier
287
	accessfileid	VARCHAR2(2000),	-- the 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
CREATE INDEX xml_access_idx6 on xml_access(guid);
306
CREATE INDEX identifier_docid_rev_log ON identifier((docid||'.'||rev));
307

    
308

    
309

    
310
/*
311
 * Index of Nodes -- table to store precomputed paths through tree for
312
 * quick searching in structured searches
313
 */
314
CREATE TABLE xml_index (
315
	nodeid		NUMBER(20),	-- the unique node id
316
	path		VARCHAR2(1000),	-- precomputed path through tree
317
	docid		VARCHAR2(250),	-- index to the document id
318
	doctype		VARCHAR2(100),	-- public id indicating document type
319
        parentnodeid    NUMBER(20),     -- id of the parent of the node
320
					-- represented by this row
321
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
322
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
323
   CONSTRAINT xml_index_docid_fk
324
		FOREIGN KEY (docid) REFERENCES xml_documents
325
);
326

    
327
/*
328
 * Index of the paths in xml_index
329
 */
330
CREATE INDEX xml_index_idx1 ON xml_index (path);
331
CREATE INDEX xml_index_idx2 ON xml_index (docid);
332
CREATE INDEX xml_index_idx3 ON xml_index (nodeid);
333

    
334

    
335
/*
336
 * Index of Paths - table to store nodes with paths specified by userst in metacat.properties
337
 */
338
CREATE TABLE xml_path_index (
339
        nodeid          NUMBER(20),     -- the unique node id
340
        docid           VARCHAR2(250),  -- index to the document id
341
        path            VARCHAR2(4000), -- precomputed path through tree
342
	    nodedata        VARCHAR2(4000), -- the data for this node e.g.,
343
        nodedatanumerical NUMBER(20),   -- the data for this node if
344
		nodedatadate TIMESTAMP,       -- the data for this node if it is a date        
345
		parentnodeid    NUMBER(20),     -- index of the parent of this node
346
        CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid),
347
        CONSTRAINT xml_path_index_docid_fk FOREIGN KEY (docid) REFERENCES xml_documents
348
 );                                                                                        
349

    
350

    
351
/*
352
 * create sequence an trigger
353
 */
354
CREATE SEQUENCE xml_path_index_id_seq;                                                                                                                                                             
355
CREATE TRIGGER xml_path_index_before_insert
356
BEFORE INSERT ON xml_path_index FOR EACH ROW
357
BEGIN
358
  SELECT xml_path_index_id_seq.nextval
359
    INTO :new.nodeid
360
    FROM dual;
361
END;
362
/
363

    
364

    
365
/*
366
 * Index of the path, nodedata, nodedatanumerical in xml_path_index
367
 */
368
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path);
369
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata);
370
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical);
371
CREATE INDEX xml_path_index_idx4 ON xml_path_index (nodedatadate);
372
CREATE INDEX xml_path_index_idx6 ON xml_path_index (docid);
373

    
374

    
375
CREATE TABLE xml_relation (
376
	relationid    NUMBER(20) PRIMARY KEY, -- unique id
377
	docid         VARCHAR2(250),          -- the docid of the package file
378
	                                      -- that this relation came from
379
        packagetype   VARCHAR2(250),          -- the type of the package
380
	subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
381
	subdoctype    VARCHAR2(128),          -- the doctype of the subject
382
	relationship  VARCHAR2(128)  NOT NULL,-- the relationship type
383
	object        VARCHAR2(512) NOT NULL, -- the object of the relation
384
	objdoctype    VARCHAR2(128),          -- the doctype of the object
385
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
386
	CONSTRAINT xml_relation_docid_fk
387
		FOREIGN KEY (docid) REFERENCES xml_documents
388
  );
389

    
390
CREATE SEQUENCE xml_relation_id_seq;
391

    
392
CREATE TRIGGER xml_relation_before_insert
393
BEFORE INSERT ON xml_relation FOR EACH ROW
394
BEGIN
395
  SELECT xml_relation_id_seq.nextval
396
    INTO :new.relationid
397
    FROM dual;
398
END;
399
/
400

    
401
/*
402
 * Table used to store all document identifiers for system metadata objects
403
 * similar restraints to identifier.  Cannot use identifier table for this 
404
 * purpose because then you have to worry about whether you insert the
405
 * data first or the systemMetadata first.
406
 */
407
CREATE TABLE systemMetadata (
408
   guid   VARCHAR2(2000),    -- the globally unique string identifier
409
   serial_version VARCHAR2(256), --the serial version of the object   
410
   date_uploaded DATE, -- the date/time the document was first submitted
411
   rights_holder VARCHAR2(250), --the user who has rights to the document, usually the first persons to upload it
412
   checksum VARCHAR2(512), --the checksum of the doc using the given algorithm (see below)
413
   checksum_algorithm VARCHAR2(250), --the algorithm used to calculate the checksum
414
   origin_member_node VARCHAR2(250), --the member node where the document was first uploaded
415
   authoritive_member_node VARCHAR2(250), --the member node that currently controls the document
416
   date_modified DATE, -- the last date/time that the file was changed
417
   submitter VARCHAR2(256), -- the user who originally submitted the doc
418
   object_format VARCHAR2(256), --the format of the object
419
   size VARCHAR2(256), --the size of the object
420
   	archived boolean,	 -- specifies whether this an archived object
421
   replication_allowed boolean,	 -- replication allowed
422
   number_replicas NUMBER(8), 	-- the number of replicas allowed
423
   obsoletes   VARCHAR2(2000),    -- the identifier of the record that this replaces
424
   obsoleted_by   VARCHAR2(2000),    -- the identifier of the record that replaces this record
425
   CONSTRAINT systemMetadata_pk 
426
		PRIMARY KEY (guid)
427
)
428

    
429
CREATE TABLE smReplicationPolicy (
430
	guid VARCHAR2(2000),	-- the globally unique string identifier of the object that the system metadata describes
431
	member_node VARCHAR(250),	 -- replication member node
432
	policy VARCHAR2(2000),	 -- the policy (preferred, blocked, etc...TBD)
433
	CONSTRAINT smReplicationPolicy_fk 
434
		FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE
435
);
436

    
437
CREATE TABLE smReplicationStatus (
438
	guid VARCHAR2(2000),	-- the globally unique string identifier of the object that the system metadata describes
439
	member_node VARCHAR(250),	 -- replication member node
440
	status VARCHAR(250),	 -- replication status
441
	date_verified DATE, 	-- the date replication was verified   
442
	CONSTRAINT smReplicationStatus_fk 
443
		FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE
444
);
445

    
446
/*
447
 * Table used to store all document identifiers in metacat.  Each identifier
448
 * has a globally unique, unconstrained string, which we will refer to as a
449
 * GUID, and a local metacat identifier, which consists of the docid
450
 * and revision fields. Each row maps one global identifier to the local
451
 * identifier (docid) used within metacat.
452
 */
453
CREATE TABLE identifier (
454
   guid   VARCHAR2(2000), -- the globally unique string identifier
455
   docid  VARCHAR2(250),  -- the local document id #
456
   rev    NUMBER(8)       -- the revision part of the local identifier
457
);
458
CREATE INDEX identifier_guid on identifier(guid);
459
CREATE INDEX identifier_docid on identifier(docid);
460
CREATE INDEX identifier_rev on identifier(rev);
461
CREATE INDEX identifier_docid_rev on identifier(docid, rev);
462

    
463

    
464
/*
465
 * the index_event table for solr-based indexing
466
 */
467
CREATE TABLE index_event (
468
	guid VARCHAR2(2000),
469
	event_action VARCHAR2(250),
470
	description VARCHAR2(2000), 
471
	event_date DATE
472
);
473

    
474
/*
475
 * accesssubtree -- table to store access subtree info
476
 */
477
CREATE TABLE xml_accesssubtree (
478
	docid		VARCHAR2(250),	-- the document id #
479
  rev 		NUMBER(10) DEFAULT 1, --the revision number of the docume
480
  controllevel VARCHAR2(50), -- the level it control -- document or subtree
481
  subtreeid VARCHAR2(250), -- the subtree id
482
	startnodeid	NUMBER(20),	-- the start node id of access subtree
483
  endnodeid NUMBER(20), -- the end node if of access subtree
484
  CONSTRAINT xml_accesssubtree_docid_fk
485
		FOREIGN KEY (docid) REFERENCES xml_documents
486
);
487

    
488
/*
489
 * Returnfields -- table to store combinations of returnfields requested
490
 *		   and the number of times this table is accessed
491
 */
492
CREATE TABLE xml_returnfield (
493
        returnfield_id     NUMBER(20),     -- the id for this returnfield entry
494
        returnfield_string VARCHAR2(2000), -- the returnfield string
495
        usage_count        NUMBER(20),     -- the number of times this string
496
                                           -- has been requested
497
        CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id)
498
);
499
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string);
500

    
501
CREATE SEQUENCE xml_returnfield_id_seq;
502

    
503
CREATE TRIGGER xml_returnfield_before_insert
504
BEFORE INSERT ON xml_returnfield FOR EACH ROW
505
BEGIN
506
  SELECT xml_returnfield_id_seq.nextval
507
    INTO :new.returnfield_id
508
    FROM dual;
509
END;
510
/
511

    
512
/*
513
 * Queryresults -- table to store queryresults for a given docid
514
 * and returnfield_id
515
 */
516
CREATE TABLE xml_queryresult(
517
  queryresult_id       NUMBER(20),     -- id for this entry
518
  returnfield_id       NUMBER(20),     -- id for the returnfield corresponding to this entry
519
  docid                VARCHAR2(250),  -- docid of the document
520
  queryresult_string   VARCHAR2(4000), -- resultant text generated for this docid and given
521
  				       -- returnfield
522
  CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id),
523
  CONSTRAINT xml_queryresult_searchid_fk
524
               FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield
525
);
526

    
527
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid);
528

    
529
CREATE SEQUENCE xml_queryresult_id_seq;
530

    
531
CREATE TRIGGER xml_queryresult_before_insert
532
BEFORE INSERT ON xml_queryresult FOR EACH ROW
533
BEGIN
534
 SELECT xml_queryresult_id_seq.nextval
535
   INTO :new.queryresult_id
536
   FROM dual;
537
END;
538
/
539

    
540

    
541

    
542

    
543
/*
544
 * Logging -- table to store metadata and data access log
545
 */
546
CREATE TABLE access_log (
547
  entryid       NUMBER(20),     -- the identifier for the log event
548
  ip_address    VARCHAR2(512),  -- the ip address inititiating the event
549
  user_agent    VARCHAR2(512),  -- the user agent for the request
550
  principal     VARCHAR2(512),  -- the user initiiating the event
551
  docid         VARCHAR2(250),	-- the document id #
552
  event         VARCHAR2(512),  -- the code symbolizing the event type
553
  date_logged   DATE,           -- the datetime on which the event occurred
554
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
555
);
556
CREATE INDEX access_log_docid ON access_log(docid);
557

    
558
CREATE SEQUENCE access_log_id_seq;
559
CREATE TRIGGER access_log_before_insert
560
BEFORE INSERT ON access_log FOR EACH ROW
561
BEGIN
562
  SELECT access_log_id_seq.nextval
563
    INTO :new.entryid
564
    FROM dual;
565
END;
566
/
567

    
568
/*
569
 * harvest_site_schedule -- table to store harvest sites and schedule info
570
 */
571
CREATE TABLE harvest_site_schedule (
572
  site_schedule_id NUMBER,         -- unique id
573
  documentlisturl  VARCHAR2(255),  -- URL of the site harvest document list
574
  ldapdn           VARCHAR2(255),  -- LDAP distinguished name for site account
575
  datenextharvest  DATE,           -- scheduled date of next harvest
576
  datelastharvest  DATE,           -- recorded date of last harvest
577
  updatefrequency  NUMBER,         -- the harvest update frequency
578
  unit             VARCHAR2(50),   -- update unit -- days weeks or months
579
  contact_email    VARCHAR2(50),   -- email address of the site contact person
580
  ldappwd          VARCHAR2(20),   -- LDAP password for site account
581
  CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
582
);
583

    
584
/*
585
 * harvest_log -- table to log entries for harvest operations
586
 */
587
CREATE TABLE harvest_log (
588
  harvest_log_id         NUMBER,         -- unique id
589
  harvest_date           DATE,           -- date of the current harvest
590
  status                 NUMBER,         -- non-zero indicates an error status
591
  message                VARCHAR2(1000), -- text message for this log entry
592
  harvest_operation_code VARCHAR2(1000),   -- the type of harvest operation
593
  site_schedule_id       NUMBER,         -- site schedule id, or 0 if no site
594
  CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
595
);
596

    
597
/*
598
 * harvest_detail_log -- table to log detailed info about documents that
599
 *                       generated errors during the harvest
600
 */
601
CREATE TABLE harvest_detail_log (
602
  detail_log_id          NUMBER,         -- unique id
603
  harvest_log_id         NUMBER,         -- ponter to the related log entry
604
  scope                  VARCHAR2(50),   -- document scope
605
  identifier             NUMBER,         -- document identifier
606
  revision               NUMBER,         -- document revision
607
  document_url           VARCHAR2(255),  -- document URL
608
  error_message          VARCHAR2(1000), -- text error message
609
  document_type          VARCHAR2(100),  -- document type
610
  CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
611
  CONSTRAINT harvest_detail_log_fk
612
        FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
613
);
614

    
615
/*
616
 * db_version -- table to store the version history of this database
617
 */
618
CREATE TABLE db_version (
619
  db_version_id   NUMBER(20),       -- the identifier for the version
620
  version         VARCHAR(250),     -- the version number
621
  status          NUMBER(20),       -- status of the version
622
  date_created    DATE,             -- the datetime on which the version was created
623
  CONSTRAINT db_version_pk PRIMARY KEY (db_version_id)
624
);
625

    
626
CREATE SEQUENCE db_version_id_seq;
627
CREATE TRIGGER db_version_before_insert
628
BEFORE INSERT ON db_version FOR EACH ROW
629
BEGIN
630
  SELECT db_version_id_seq.nextval
631
    INTO :new.db_version_id
632
    FROM dual;
633
END;
634
/
635

    
636
/*
637
 * scheduled_job -- table to store scheduled jobs
638
 */
639
CREATE TABLE scheduled_job (
640
  id NUMBER(20) NOT NULL default nextval('scheduled_job_id_seq'),
641
  date_created TIMESTAMP NOT NULL,
642
  date_updated TIMESTAMP NOT NULL,
643
  status VARCHAR2(64) NOT NULL,
644
  name VARCHAR2(512) NOT NULL,
645
  trigger_name VARCHAR2(512) NOT NULL,
646
  group_name VARCHAR2(512) NOT NULL,
647
  class_name VARCHAR2(1024) NOT NULL,
648
  start_time TIMESTAMP NOT NULL,
649
  interval_value NUMBER NOT NULL,
650
  interval_unit VARCHAR2(8) NOT NULL,
651
  CONSTRAINT scheduled_job_pk PRIMARY KEY (id),
652
  CONSTRAINT scheduled_job_uk UNIQUE (name)
653
);
654

    
655
CREATE SEQUENCE scheduled_job_id_seq;
656
CREATE TRIGGER scheduled_job_before_insert
657
BEFORE INSERT ON scheduled_job FOR EACH ROW
658
BEGIN
659
  SELECT scheduled_job_id_seq.nextval
660
    INTO :new.id
661
    FROM dual;
662
END;
663
/
664

    
665
/*
666
 * scheduled_job_params -- table to store scheduled job parameters
667
 */
668
CREATE TABLE scheduled_job_params (
669
  id NUMBER(20)  NOT NULL default nextval('scheduled_job_params_id_seq'),
670
  date_created TIMESTAMP NOT NULL,
671
  date_updated TIMESTAMP  NOT NULL,
672
  status VARCHAR2(64)  NOT NULL,
673
  job_id NUMBER(20) NOT NULL,
674
  key VARCHAR2(64) NOT NULL,
675
  value VARCHAR2(1024) NOT NULL,
676
  CONSTRAINT scheduled_job_params_pk PRIMARY KEY (id),
677
  CONSTRAINT scheduled_job_params_fk
678
        FOREIGN KEY (job_id) REFERENCES scheduled_job(id)
679
);
680

    
681
CREATE SEQUENCE scheduled_job_params_id_seq;
682
CREATE TRIGGER scheduled_job_params_before_insert
683
BEFORE INSERT ON scheduled_job_params FOR EACH ROW
684
BEGIN
685
  SELECT scheduled_job_id_params_seq.nextval
686
    INTO :new.id
687
    FROM dual;
688
END;
689
/
690

    
(83-83/85)