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: sgarg $'
7
 *     '$Date: 2005-03-17 17:58:02 -0800 (Thu, 17 Mar 2005) $'
8
 * '$Revision: 2422 $'
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 xml_documents_id_seq;
36
DROP SEQUENCE accession_number_id_seq;
37
DROP SEQUENCE access_log_seq;
38
DROP SEQUENCE xml_returnfield_id_seq;
39
DROP SEQUENCE xml_queryresult_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 accession_number_before_insert;
48
DROP TRIGGER access_log_before_insert;
49
DROP TRIGGER xml_returnfield_before_insert;
50
DROP TRIGGER xml_queryresult_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;
59
DROP TABLE xml_nodes;
60
DROP TABLE xml_replication;
61
DROP TABLE xml_catalog;
62
DROP TABLE accession_number;
63
DROP TABLE access_log;
64
DROP TABLE harvest_site_schedule;
65
DROP TABLE harvest_detail_log;
66
DROP TABLE harvest_log;
67
DROP TABLE xml_returnfield;
68
DROP TABLE xml_queryresult;
69

    
70
/*
71
 *Replication -- table to store servers that metacat is replicated to
72
 */
73
CREATE TABLE xml_replication (
74
  serverid      NUMBER(20),
75
  server        VARCHAR2(512),
76
  last_checked  DATE,
77
  replicate     NUMBER(1),
78
  datareplicate NUMBER(1),
79
  hub NUMBER(1),
80
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
81
);
82

    
83
CREATE SEQUENCE xml_replication_id_seq;
84
CREATE TRIGGER xml_replication_before_insert
85
BEFORE INSERT ON xml_replication FOR EACH ROW
86
BEGIN
87
  SELECT xml_replication_id_seq.nextval
88
    INTO :new.serverid
89
    FROM dual;
90
END;
91
/
92

    
93
INSERT INTO xml_replication (server, replicate, datareplicate, hub)
94
 VALUES ('localhost', '0', '0', '0');
95

    
96
/*
97
 * Nodes -- table to store XML Nodes (both elements and attributes)
98
 */
99
CREATE SEQUENCE xml_nodes_id_seq;
100
CREATE TABLE xml_nodes (
101
	nodeid		NUMBER(20),	-- the unique node id (pk)
102
	nodeindex	NUMBER(10),	-- order of nodes within parent
103
	nodetype	VARCHAR2(20),	-- type (DOCUMENT, COMMENT, PI,
104
					-- ELEMENT, ATTRIBUTE, TEXT)
105
	nodename	VARCHAR2(250),	-- the name of an element or attribute
106
	nodeprefix	VARCHAR2(50),	-- the namespace prefix of an element
107
                                        -- or attribute
108
	nodedata	VARCHAR2(4000), -- the data for this node (e.g.,
109
					-- for TEXT it is the content)
110
	parentnodeid	NUMBER(20),	-- index of the parent of this node
111
	rootnodeid	NUMBER(20),	-- index of the root node of this tree
112
	docid		VARCHAR2(250),	-- index to the document id
113
	date_created	DATE,
114
	date_updated	DATE,
115
	nodedatanumerical NUMBER,       -- the data for this node if
116
					-- it is a number
117
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
118
   CONSTRAINT xml_nodes_root_fk
119
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
120
   CONSTRAINT xml_nodes_parent_fk
121
		FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
122
);
123
CREATE TRIGGER xml_nodes_before_insert
124
BEFORE INSERT ON xml_nodes FOR EACH ROW
125
BEGIN
126
  SELECT xml_nodes_id_seq.nextval
127
    INTO :new.nodeid
128
    FROM dual;
129
END;
130
/
131

    
132
/*
133
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
134
 */
135
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
136
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
137
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
138

    
139
/*
140
 * XML Catalog -- table to store all external sources for XML documents
141
 */
142
CREATE TABLE xml_catalog (
143
	catalog_id	NUMBER(20),	-- the id for this catalog entry
144
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
145
					-- (e.g., DTD, XSD, XSL)
146
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
147
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
148
	public_id	VARCHAR2(500),	-- the unique id for this type
149
	system_id	VARCHAR2(1000),	-- the local location of the object
150
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
151
   CONSTRAINT xml_catalog_uk UNIQUE
152
		(entry_type, source_doctype, target_doctype, public_id)
153
);
154

    
155
CREATE SEQUENCE xml_catalog_id_seq;
156

    
157
CREATE TRIGGER xml_catalog_before_insert
158
BEFORE INSERT ON xml_catalog FOR EACH ROW
159
BEGIN
160
  SELECT xml_catalog_id_seq.nextval
161
    INTO :new.catalog_id
162
    FROM dual;
163
END;
164
/
165

    
166
/*
167
 * Documents -- table to store XML documents
168
 */
169
CREATE TABLE xml_documents (
170
	docid		VARCHAR2(250),	-- the document id #
171
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
172
	docname		VARCHAR2(100),	-- usually the root element name
173
	doctype		VARCHAR2(100),	-- public id indicating document type
174
	user_owner	VARCHAR2(100),	-- the user owned the document
175
	user_updated	VARCHAR2(100),	-- the user updated the document
176
	server_location NUMBER(20),	-- the server on which this document
177
                                        -- originates
178
	rev 		NUMBER(10) DEFAULT 1,--the revision number of the docume
179
	date_created	DATE,
180
	date_updated	DATE,
181
	public_access	NUMBER(1),	-- flag for public access
182
        catalog_id      NUMBER(20),	-- reference to xml_catalog
183
   CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
184
   CONSTRAINT xml_documents_rep_fk
185
    		FOREIGN KEY (server_location) REFERENCES xml_replication,
186
   CONSTRAINT xml_documents_root_fk
187
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
188
   CONSTRAINT xml_documents_catalog_fk
189
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
190
);
191

    
192
/*
193
 * Index of <docid,doctype> in xml_document
194
 */
195
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
196

    
197
/*
198
 * Revised Documents -- table to store XML documents saved after an UPDATE
199
 *                    or DELETE
200
 */
201
CREATE TABLE xml_revisions (
202
	revisionid	NUMBER(20),	-- the revision number we are saving
203
	docid		VARCHAR2(250),	-- the document id #
204
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
205
	docname		VARCHAR2(100),	-- usually the root element name
206
	doctype		VARCHAR2(100),	-- public id indicating document type
207
	user_owner	VARCHAR2(100),
208
	user_updated	VARCHAR2(100),
209
	server_location NUMBER(20),
210
	rev		NUMBER(10),
211
	date_created	DATE,
212
	date_updated	DATE,
213
	public_access	NUMBER(1),	-- flag for public access
214
        catalog_id      NUMBER(20),	-- reference to xml_catalog
215
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
216
   CONSTRAINT xml_revisions_rep_fk
217
		FOREIGN KEY (server_location) REFERENCES xml_replication,
218
   CONSTRAINT xml_revisions_root_fk
219
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
220
   CONSTRAINT xml_revisions_catalog_fk
221
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
222
);
223

    
224
CREATE SEQUENCE xml_revisions_id_seq;
225

    
226
CREATE TRIGGER xml_revisions_before_insert
227
BEFORE INSERT ON xml_revisions FOR EACH ROW
228
BEGIN
229
  SELECT xml_revisions_id_seq.nextval
230
    INTO :new.revisionid
231
    FROM dual;
232
END;
233
/
234

    
235
/*
236
 * ACL -- table to store ACL for XML documents by principals
237
 */
238
CREATE TABLE xml_access (
239
	docid		VARCHAR2(250),	-- the document id #
240
	accessfileid	VARCHAR2(250),	-- the document id # for the access file
241
	principal_name	VARCHAR2(100),	-- name of user, group, etc.
242
	permission	NUMBER(1),	-- "read", "write", "all"
243
	perm_type	VARCHAR2(32),	-- "allowed" or "denied"
244
	perm_order	VARCHAR2(32),	-- "allow first" or "deny first"
245
	begin_time	DATE,		-- the time that permission begins
246
	end_time	DATE,		-- the time that permission ends
247
	ticket_count	NUMBER(5),	-- ticket counter for that permission
248
  subtreeid VARCHAR2(32), -- sub tree id
249
  startnodeid NUMBER(20), -- start node for sub tree
250
  endnodeid NUMBER(20),    -- end node for sub tree
251
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
252
   CONSTRAINT xml_access_accessfileid_fk
253
		FOREIGN KEY (accessfileid) REFERENCES xml_documents
254
);
255

    
256
/*
257
 * Index of Nodes -- table to store precomputed paths through tree for
258
 * quick searching in structured searches
259
 */
260
CREATE TABLE xml_index (
261
	nodeid		NUMBER(20),	-- the unique node id
262
	path		VARCHAR2(1000),	-- precomputed path through tree
263
	docid		VARCHAR2(250),	-- index to the document id
264
	doctype		VARCHAR2(100),	-- public id indicating document type
265
        parentnodeid    NUMBER(20),     -- id of the parent of the node
266
					-- represented by this row
267
	nodedata        VARCHAR2(4000), -- the data for the given path
268
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
269
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
270
   CONSTRAINT xml_index_docid_fk
271
		FOREIGN KEY (docid) REFERENCES xml_documents
272
);
273

    
274
/*
275
 * Index of the paths in xml_index
276
 */
277
CREATE INDEX xml_index_idx1 ON xml_index (path);
278
CREATE INDEX xml_index_idx2 ON xml_index (docid);
279

    
280
CREATE TABLE xml_relation (
281
	relationid    NUMBER(20) PRIMARY KEY, -- unique id
282
	docid         VARCHAR2(250),          -- the docid of the package file
283
	                                      -- that this relation came from
284
        packagetype   VARCHAR2(250),          -- the type of the package
285
	subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
286
	subdoctype    VARCHAR2(128),          -- the doctype of the subject
287
	relationship  VARCHAR2(128)  NOT NULL,-- the relationship type
288
	object        VARCHAR2(512) NOT NULL, -- the object of the relation
289
	objdoctype    VARCHAR2(128),          -- the doctype of the object
290
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
291
	CONSTRAINT xml_relation_docid_fk
292
		FOREIGN KEY (docid) REFERENCES xml_documents
293
  );
294

    
295
CREATE SEQUENCE xml_relation_id_seq;
296

    
297
CREATE TRIGGER xml_relation_before_insert
298
BEFORE INSERT ON xml_relation FOR EACH ROW
299
BEGIN
300
  SELECT xml_relation_id_seq.nextval
301
    INTO :new.relationid
302
    FROM dual;
303
END;
304
/
305

    
306
/*
307
 * Table used as Unique ID generator for the uniqueid part of Accession#
308
 */
309
CREATE SEQUENCE accession_number_id_seq;
310
CREATE TABLE accession_number (
311
	uniqueid	NUMBER(20) PRIMARY KEY,
312
	site_code	VARCHAR2(100),
313
	date_created	DATE
314
);
315
CREATE TRIGGER accession_number_before_insert
316
BEFORE INSERT ON accession_number FOR EACH ROW
317
BEGIN
318
  SELECT accession_number_id_seq.nextval
319
    INTO :new.uniqueid
320
    FROM dual;
321
END;
322
/
323

    
324
/*
325
 * accesssubtree -- table to store access subtree info
326
 */
327
CREATE TABLE xml_accesssubtree (
328
	docid		VARCHAR2(250),	-- the document id #
329
  rev 		NUMBER(10) DEFAULT 1, --the revision number of the docume
330
  controllevel VARCHAR2(50), -- the level it control -- document or subtree
331
  subtreeid VARCHAR2(250), -- the subtree id
332
	startnodeid	NUMBER(20),	-- the start node id of access subtree
333
  endnodeid NUMBER(20), -- the end node if of access subtree
334
  CONSTRAINT xml_accesssubtree_docid_fk
335
		FOREIGN KEY (docid) REFERENCES xml_documents
336
);
337

    
338
/*
339
 * Returnfields -- table to store combinations of returnfields requested
340
 *		   and the number of times this table is accessed
341
 */
342
CREATE TABLE xml_returnfield (
343
        returnfield_id     NUMBER(20),     -- the id for this returnfield entry
344
        returnfield_string VARCHAR2(2000), -- the returnfield string
345
        usage_count        NUMBER(20),     -- the number of times this string
346
                                           -- has been requested
347
        CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id)
348
);
349
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string);
350

    
351
CREATE SEQUENCE xml_returnfield_id_seq;
352

    
353
CREATE TRIGGER xml_returnfield_before_insert
354
BEFORE INSERT ON xml_returnfield FOR EACH ROW
355
BEGIN
356
  SELECT xml_returnfield_id_seq.nextval
357
    INTO :new.returnfield_id
358
    FROM dual;
359
END;
360
/
361

    
362
/*
363
 * Queryresults -- table to store queryresults for a given docid
364
 * and returnfield_id
365
 */
366
CREATE TABLE xml_queryresult(
367
  queryresult_id       NUMBER(20),     -- id for this entry
368
  returnfield_id       NUMBER(20),     -- id for the returnfield corresponding to this entry
369
  docid                VARCHAR2(250),  -- docid of the document
370
  queryresult_string   VARCHAR2(4000), -- resultant text generated for this docid and given
371
  				       -- returnfield
372
  CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id),
373
  CONSTRAINT xml_queryresult_searchid_fk
374
               FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield
375
);
376

    
377
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid);
378

    
379
CREATE SEQUENCE xml_queryresult_id_seq;
380

    
381
CREATE TRIGGER xml_queryresult_before_insert
382
BEFORE INSERT ON xml_queryresult FOR EACH ROW
383
BEGIN
384
 SELECT xml_queryresult_id_seq.nextval
385
   INTO :new.queryresult_id
386
   FROM dual;
387
END;
388
/
389

    
390
/*
391
 * Logging -- table to store metadata and data access log
392
 */
393
CREATE TABLE access_log (
394
  entryid       NUMBER(20),     -- the identifier for the log event
395
  ip_address    VARCHAR2(512),  -- the ip address inititiating the event
396
  principal     VARCHAR2(512),  -- the user initiiating the event
397
  docid         VARCHAR2(250),	-- the document id #
398
  event         VARCHAR2(512),  -- the code symbolizing the event type
399
  date_logged   DATE,           -- the datetime on which the event occurred
400
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
401
);
402

    
403
CREATE SEQUENCE access_log_id_seq;
404
CREATE TRIGGER access_log_before_insert
405
BEFORE INSERT ON access_log FOR EACH ROW
406
BEGIN
407
  SELECT access_log_id_seq.nextval
408
    INTO :new.entryid
409
    FROM dual;
410
END;
411
/
412

    
413
/*
414
 * harvest_site_schedule -- table to store harvest sites and schedule info
415
 */
416
CREATE TABLE harvest_site_schedule (
417
  site_schedule_id NUMBER,         -- unique id
418
  documentlisturl  VARCHAR2(255),  -- URL of the site harvest document list
419
  ldapdn           VARCHAR2(255),  -- LDAP distinguished name for site account
420
  datenextharvest  DATE,           -- scheduled date of next harvest
421
  datelastharvest  DATE,           -- recorded date of last harvest
422
  updatefrequency  NUMBER,         -- the harvest update frequency
423
  unit             VARCHAR2(50),   -- update unit -- days weeks or months
424
  contact_email    VARCHAR2(50),   -- email address of the site contact person
425
  ldappwd          VARCHAR2(20),   -- LDAP password for site account
426
  CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
427
);
428

    
429
/*
430
 * harvest_log -- table to log entries for harvest operations
431
 */
432
CREATE TABLE harvest_log (
433
  harvest_log_id         NUMBER,         -- unique id
434
  harvest_date           DATE,           -- date of the current harvest
435
  status                 NUMBER,         -- non-zero indicates an error status
436
  message                VARCHAR2(1000), -- text message for this log entry
437
  harvest_operation_code VARCHAR2(30),   -- the type of harvest operation
438
  site_schedule_id       NUMBER,         -- site schedule id, or 0 if no site
439
  CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
440
);
441

    
442
/*
443
 * harvest_detail_log -- table to log detailed info about documents that
444
 *                       generated errors during the harvest
445
 */
446
CREATE TABLE harvest_detail_log (
447
  detail_log_id          NUMBER,         -- unique id
448
  harvest_log_id         NUMBER,         -- ponter to the related log entry
449
  scope                  VARCHAR2(50),   -- document scope
450
  identifier             NUMBER,         -- document identifier
451
  revision               NUMBER,         -- document revision
452
  document_url           VARCHAR2(255),  -- document URL
453
  error_message          VARCHAR2(1000), -- text error message
454
  document_type          VARCHAR2(100),  -- document type
455
  CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
456
  CONSTRAINT harvest_detail_log_fk
457
        FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
458
);
459

    
(25-25/25)