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: 2004-12-30 15:51:24 -0800 (Thu, 30 Dec 2004) $'
8
 * '$Revision: 2359 $'
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
	nodedatanumerical NUMBER,       -- the data for this node if 
109
					-- it is a number
110
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
111
   CONSTRAINT xml_nodes_root_fk 
112
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
113
   CONSTRAINT xml_nodes_parent_fk 
114
		FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
115
);
116
CREATE TRIGGER xml_nodes_before_insert
117
BEFORE INSERT ON xml_nodes FOR EACH ROW
118
BEGIN
119
  SELECT xml_nodes_id_seq.nextval
120
    INTO :new.nodeid
121
    FROM dual;     
122
END;    
123
/
124
                               
125
/* 
126
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
127
 */
128
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
129
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
130
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
131

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

    
148
CREATE SEQUENCE xml_catalog_id_seq;
149

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

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

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

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

    
217
CREATE SEQUENCE xml_revisions_id_seq;
218

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

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

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

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

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

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

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

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

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

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

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

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

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

    
(24-24/24)