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: jones $'
7
 *     '$Date: 2004-09-15 08:56:46 -0700 (Wed, 15 Sep 2004) $'
8
 * '$Revision: 2276 $'
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
               
39
/* Drop triggers are not necessary */
40
DROP TRIGGER xml_nodes_before_insert;
41
DROP TRIGGER xml_revisions_before_insert;
42
DROP TRIGGER xml_catalog_before_insert;
43
DROP TRIGGER xml_relation_before_insert;
44
DROP TRIGGER xml_replication_before_insert;
45
DROP TRIGGER accession_number_before_insert;
46
DROP TRIGGER access_log_before_insert;
47

    
48
DROP TABLE xml_index;
49
DROP TABLE xml_access;
50
DROP TABLE xml_accesssubtree;
51
DROP TABLE xml_revisions;
52
DROP TABLE xml_relation;
53
DROP TABLE xml_documents;
54
DROP TABLE xml_nodes;
55
DROP TABLE xml_replication;
56
DROP TABLE xml_catalog;
57
DROP TABLE accession_number;
58
DROP TABLE access_log;
59
DROP TABLE harvest_site_schedule;
60
DROP TABLE harvest_detail_log;
61
DROP TABLE harvest_log;
62

    
63
/*
64
 *Replication -- table to store servers that metacat is replicated to
65
 */
66
CREATE TABLE xml_replication (
67
  serverid      NUMBER(20),
68
  server        VARCHAR2(512),
69
  last_checked  DATE,
70
  replicate     NUMBER(1),
71
  datareplicate NUMBER(1),
72
  hub NUMBER(1),
73
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
74
);  
75
  
76
CREATE SEQUENCE xml_replication_id_seq;
77
CREATE TRIGGER xml_replication_before_insert
78
BEFORE INSERT ON xml_replication FOR EACH ROW
79
BEGIN
80
  SELECT xml_replication_id_seq.nextval
81
    INTO :new.serverid
82
    FROM dual;
83
END;
84
/
85

    
86
INSERT INTO xml_replication (server, replicate, datareplicate, hub)
87
 VALUES ('localhost', '0', '0', '0');
88

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

    
130
/* 
131
 * XML Catalog -- table to store all external sources for XML documents
132
 */
133
CREATE TABLE xml_catalog (
134
	catalog_id	NUMBER(20),	-- the id for this catalog entry
135
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
136
					-- (e.g., DTD, XSD, XSL)
137
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
138
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
139
	public_id	VARCHAR2(500),	-- the unique id for this type
140
	system_id	VARCHAR2(1000),	-- the local location of the object
141
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
142
   CONSTRAINT xml_catalog_uk UNIQUE 
143
		(entry_type, source_doctype, target_doctype, public_id)
144
);
145

    
146
CREATE SEQUENCE xml_catalog_id_seq;
147

    
148
CREATE TRIGGER xml_catalog_before_insert
149
BEFORE INSERT ON xml_catalog FOR EACH ROW
150
BEGIN
151
  SELECT xml_catalog_id_seq.nextval
152
    INTO :new.catalog_id
153
    FROM dual;
154
END;
155
/
156

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

    
183
/* 
184
 * Index of <docid,doctype> in xml_document
185
 */
186
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
187

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

    
215
CREATE SEQUENCE xml_revisions_id_seq;
216

    
217
CREATE TRIGGER xml_revisions_before_insert
218
BEFORE INSERT ON xml_revisions FOR EACH ROW
219
BEGIN
220
  SELECT xml_revisions_id_seq.nextval
221
    INTO :new.revisionid
222
    FROM dual;
223
END;
224
/
225

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

    
247
/* 
248
 * Index of Nodes -- table to store precomputed paths through tree for 
249
 * quick searching in structured searches
250
 */
251
CREATE TABLE xml_index (
252
	nodeid		NUMBER(20),	-- the unique node id
253
	path		VARCHAR2(1000),	-- precomputed path through tree
254
	docid		VARCHAR2(250),	-- index to the document id
255
	doctype		VARCHAR2(100),	-- public id indicating document type
256
        parentnodeid    NUMBER(20),     -- id of the parent of the node 
257
					-- represented by this row
258
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
259
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
260
   CONSTRAINT xml_index_docid_fk 
261
		FOREIGN KEY (docid) REFERENCES xml_documents
262
);
263

    
264
/* 
265
 * Index of the paths in xml_index 
266
 */
267
CREATE INDEX xml_index_idx1 ON xml_index (path);
268

    
269
CREATE TABLE xml_relation (
270
	relationid    NUMBER(20) PRIMARY KEY, -- unique id
271
	docid         VARCHAR2(250),          -- the docid of the package file
272
	                                      -- that this relation came from
273
        packagetype   VARCHAR2(250),          -- the type of the package
274
	subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
275
	subdoctype    VARCHAR2(128),          -- the doctype of the subject
276
	relationship  VARCHAR2(128)  NOT NULL,-- the relationship type
277
	object        VARCHAR2(512) NOT NULL, -- the object of the relation
278
	objdoctype    VARCHAR2(128),          -- the doctype of the object
279
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
280
	CONSTRAINT xml_relation_docid_fk 
281
		FOREIGN KEY (docid) REFERENCES xml_documents
282
  );
283

    
284
CREATE SEQUENCE xml_relation_id_seq;
285
  
286
CREATE TRIGGER xml_relation_before_insert
287
BEFORE INSERT ON xml_relation FOR EACH ROW
288
BEGIN
289
  SELECT xml_relation_id_seq.nextval
290
    INTO :new.relationid
291
    FROM dual;
292
END;                                   
293
/
294

    
295
/* 
296
 * Table used as Unique ID generator for the uniqueid part of Accession#
297
 */
298
CREATE SEQUENCE accession_number_id_seq;
299
CREATE TABLE accession_number (
300
	uniqueid	NUMBER(20) PRIMARY KEY,
301
	site_code	VARCHAR2(100),
302
	date_created	DATE
303
);
304
CREATE TRIGGER accession_number_before_insert
305
BEFORE INSERT ON accession_number FOR EACH ROW
306
BEGIN
307
  SELECT accession_number_id_seq.nextval
308
    INTO :new.uniqueid
309
    FROM dual;
310
END;                                   
311
/
312

    
313
/* 
314
 * accesssubtree -- table to store access subtree info 
315
 */
316
CREATE TABLE xml_accesssubtree (
317
	docid		VARCHAR2(250),	-- the document id #
318
  rev 		NUMBER(10) DEFAULT 1, --the revision number of the docume
319
  controllevel VARCHAR2(50), -- the level it control -- document or subtree
320
  subtreeid VARCHAR2(250), -- the subtree id 
321
	startnodeid	NUMBER(20),	-- the start node id of access subtree
322
  endnodeid NUMBER(20), -- the end node if of access subtree
323
  CONSTRAINT xml_accesssubtree_docid_fk 
324
		FOREIGN KEY (docid) REFERENCES xml_documents
325
);
326

    
327
/*
328
 * Logging -- table to store metadata and data access log
329
 */
330
CREATE TABLE access_log (
331
  entryid       NUMBER(20),     -- the identifier for the log event
332
  ip_address    VARCHAR2(512),  -- the ip address inititiating the event
333
  principal     VARCHAR2(512),  -- the user initiiating the event
334
  docid         VARCHAR2(250),	-- the document id #
335
  event         VARCHAR2(512),  -- the code symbolizing the event type
336
  date_logged   DATE,           -- the datetime on which the event occurred
337
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
338
);
339

    
340
CREATE SEQUENCE access_log_id_seq;
341
CREATE TRIGGER access_log_before_insert
342
BEFORE INSERT ON access_log FOR EACH ROW
343
BEGIN
344
  SELECT access_log_id_seq.nextval
345
    INTO :new.entryid
346
    FROM dual;
347
END;
348
/
349

    
350
/* 
351
 * harvest_site_schedule -- table to store harvest sites and schedule info
352
 */
353
CREATE TABLE harvest_site_schedule (
354
  site_schedule_id NUMBER,         -- unique id
355
  documentlisturl  VARCHAR2(255),  -- URL of the site harvest document list
356
  ldapdn           VARCHAR2(255),  -- LDAP distinguished name for site account
357
  datenextharvest  DATE,           -- scheduled date of next harvest
358
  datelastharvest  DATE,           -- recorded date of last harvest
359
  updatefrequency  NUMBER,         -- the harvest update frequency
360
  unit             VARCHAR2(50),   -- update unit -- days weeks or months
361
  contact_email    VARCHAR2(50),   -- email address of the site contact person
362
  ldappwd          VARCHAR2(20),   -- LDAP password for site account
363
  CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
364
);
365

    
366
/* 
367
 * harvest_log -- table to log entries for harvest operations
368
 */
369
CREATE TABLE harvest_log (
370
  harvest_log_id         NUMBER,         -- unique id
371
  harvest_date           DATE,           -- date of the current harvest
372
  status                 NUMBER,         -- non-zero indicates an error status
373
  message                VARCHAR2(1000), -- text message for this log entry
374
  harvest_operation_code VARCHAR2(30),   -- the type of harvest operation
375
  site_schedule_id       NUMBER,         -- site schedule id, or 0 if no site
376
  CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
377
);
378

    
379
/* 
380
 * harvest_detail_log -- table to log detailed info about documents that
381
 *                       generated errors during the harvest
382
 */
383
CREATE TABLE harvest_detail_log (
384
  detail_log_id          NUMBER,         -- unique id
385
  harvest_log_id         NUMBER,         -- ponter to the related log entry
386
  scope                  VARCHAR2(50),   -- document scope
387
  identifier             NUMBER,         -- document identifier
388
  revision               NUMBER,         -- document revision
389
  document_url           VARCHAR2(255),  -- document URL
390
  error_message          VARCHAR2(1000), -- text error message
391
  document_type          VARCHAR2(100),  -- document type
392
  CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
393
  CONSTRAINT harvest_detail_log_fk 
394
        FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
395
);
396

    
(3-3/23)