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: costa $'
7
 *     '$Date: 2004-04-08 09:23:49 -0700 (Thu, 08 Apr 2004) $'
8
 * '$Revision: 2112 $'
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 accnum_uniqueid_seq;
36
DROP SEQUENCE xml_documents_id_seq;
37
DROP SEQUENCE accession_number_id_seq;
38
DROP SEQUENCE access_log_seq;
39
               
40
/* Drop triggers are not necessary */
41
DROP TRIGGER xml_nodes_before_insert;
42
DROP TRIGGER xml_revisions_before_insert;
43
DROP TRIGGER xml_catalog_before_insert;
44
DROP TRIGGER xml_relation_before_insert;
45
DROP TRIGGER xml_replication_before_insert;
46
DROP TRIGGER accession_number_before_insert;
47
DROP TRIGGER access_log_before_insert;
48

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

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

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

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

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

    
147
CREATE SEQUENCE xml_catalog_id_seq;
148

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

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

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

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

    
216
CREATE SEQUENCE xml_revisions_id_seq;
217

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

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

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

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

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

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

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

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

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

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

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

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

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

    
(20-20/21)