Project

General

Profile

1
/*
2
 * xmltables.sql -- Create or replace tables for storing XML in the db
3
 *
4
 *      Purpose: creates tables needed for XML database
5
 * 
6
 *      Created: 12 September 1999
7
 *       Author: Matt Jones
8
 * Organization: National Center for Ecological Analysis and Synthesis
9
 *    Copyright: 2000 Regents of the University of California and the
10
 *               National Center for Ecological Analysis and Synthesis
11
 *  For Details: http://www.nceas.ucsb.edu/
12
 *    File Info: '$Id: xmltables.sql 1604 2003-04-23 03:55:06Z tao $'
13
 *
14
 */
15

    
16
/*
17
 * Drop all of the objects in proper order
18
 */
19
set echo off
20

    
21
DROP SEQUENCE xml_nodes_id_seq;
22
DROP SEQUENCE xml_revisions_id_seq;
23
DROP SEQUENCE xml_catalog_id_seq;
24
DROP SEQUENCE xml_relation_id_seq;
25
DROP SEQUENCE xml_replication_id_seq;
26
DROP SEQUENCE accnum_uniqueid_seq;
27
DROP SEQUENCE xml_documents_id_seq;
28
DROP SEQUENCE accession_number_id_seq;
29
               
30
/* Drop triggers are not necessary */
31
DROP TRIGGER xml_nodes_before_insert;
32
DROP TRIGGER xml_revisions_before_insert;
33
DROP TRIGGER xml_catalog_before_insert;
34
DROP TRIGGER xml_relation_before_insert;
35
DROP TRIGGER xml_replication_before_insert;
36
DROP TRIGGER accession_number_before_insert;
37

    
38
DROP TABLE xml_index;
39
DROP TABLE xml_access;
40
DROP TABLE xml_accesssubtree;
41
DROP TABLE xml_revisions;
42
DROP TABLE xml_relation;
43
DROP TABLE xml_documents;
44
DROP TABLE xml_nodes;
45
DROP TABLE xml_replication;
46
DROP TABLE xml_catalog;
47
DROP TABLE accession_number;
48

    
49
/*
50
 *Replication -- table to store servers that metacat is replicated to
51
 */
52
CREATE TABLE xml_replication (
53
  serverid      NUMBER(20),
54
  server        VARCHAR2(512),
55
  last_checked  DATE,
56
  replicate     NUMBER(1),
57
  datareplicate NUMBER(1),
58
  hub NUMBER(1),
59
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
60
);  
61
  
62
CREATE SEQUENCE xml_replication_id_seq;
63
CREATE TRIGGER xml_replication_before_insert
64
BEFORE INSERT ON xml_replication FOR EACH ROW
65
BEGIN
66
  SELECT xml_replication_id_seq.nextval
67
    INTO :new.serverid
68
    FROM dual;
69
END;
70
/
71

    
72
INSERT INTO xml_replication (server, replicate, datareplicate, hub)
73
 VALUES ('localhost', '0', '0', '0');
74

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

    
116
/* 
117
 * XML Catalog -- table to store all external sources for XML documents
118
 */
119
CREATE TABLE xml_catalog (
120
	catalog_id	NUMBER(20),	-- the id for this catalog entry
121
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
122
					-- (e.g., DTD, XSD, XSL)
123
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
124
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
125
	public_id	VARCHAR2(500),	-- the unique id for this type
126
	system_id	VARCHAR2(1000),	-- the local location of the object
127
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
128
   CONSTRAINT xml_catalog_uk UNIQUE 
129
		(entry_type, source_doctype, target_doctype, public_id)
130
);
131

    
132
CREATE SEQUENCE xml_catalog_id_seq;
133

    
134
CREATE TRIGGER xml_catalog_before_insert
135
BEFORE INSERT ON xml_catalog FOR EACH ROW
136
BEGIN
137
  SELECT xml_catalog_id_seq.nextval
138
    INTO :new.catalog_id
139
    FROM dual;
140
END;
141
/
142

    
143
/* 
144
 * Documents -- table to store XML documents
145
 */
146
CREATE TABLE xml_documents (
147
	docid		VARCHAR2(250),	-- the document id #
148
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
149
	docname		VARCHAR2(100),	-- usually the root element name
150
	doctype		VARCHAR2(100),	-- public id indicating document type
151
	user_owner	VARCHAR2(100),	-- the user owned the document
152
	user_updated	VARCHAR2(100),	-- the user updated the document
153
	server_location NUMBER(20),	-- the server on which this document 
154
                                        -- originates
155
	rev 		NUMBER(10) DEFAULT 1,--the revision number of the docume
156
	date_created	DATE,
157
	date_updated	DATE,
158
	public_access	NUMBER(1),	-- flag for public access
159
        catalog_id      NUMBER(20),	-- reference to xml_catalog 
160
   CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
161
   CONSTRAINT xml_documents_rep_fk
162
    		FOREIGN KEY (server_location) REFERENCES xml_replication, 
163
   CONSTRAINT xml_documents_root_fk 
164
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
165
   CONSTRAINT xml_documents_catalog_fk 
166
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
167
);
168

    
169
/* 
170
 * Index of <docid,doctype> in xml_document
171
 */
172
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
173

    
174
/* 
175
 * Revised Documents -- table to store XML documents saved after an UPDATE
176
 *                    or DELETE
177
 */
178
CREATE TABLE xml_revisions (
179
	revisionid	NUMBER(20),	-- the revision number we are saving
180
	docid		VARCHAR2(250),	-- the document id #
181
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
182
	docname		VARCHAR2(100),	-- usually the root element name
183
	doctype		VARCHAR2(100),	-- public id indicating document type
184
	user_owner	VARCHAR2(100),
185
	user_updated	VARCHAR2(100),
186
	server_location NUMBER(20),
187
	rev		NUMBER(10),
188
	date_created	DATE,
189
	date_updated	DATE,
190
	public_access	NUMBER(1),	-- flag for public access
191
        catalog_id      NUMBER(20),	-- reference to xml_catalog 
192
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
193
   CONSTRAINT xml_revisions_rep_fk
194
		FOREIGN KEY (server_location) REFERENCES xml_replication,
195
   CONSTRAINT xml_revisions_root_fk 
196
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
197
   CONSTRAINT xml_revisions_catalog_fk 
198
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
199
);
200

    
201
CREATE SEQUENCE xml_revisions_id_seq;
202

    
203
CREATE TRIGGER xml_revisions_before_insert
204
BEFORE INSERT ON xml_revisions FOR EACH ROW
205
BEGIN
206
  SELECT xml_revisions_id_seq.nextval
207
    INTO :new.revisionid
208
    FROM dual;
209
END;
210
/
211

    
212
/* 
213
 * ACL -- table to store ACL for XML documents by principals
214
 */
215
CREATE TABLE xml_access (
216
	docid		VARCHAR2(250),	-- the document id #
217
	accessfileid	VARCHAR2(250),	-- the document id # for the access file
218
	principal_name	VARCHAR2(100),	-- name of user, group, etc.
219
	permission	NUMBER(1),	-- "read", "write", "all"
220
	perm_type	VARCHAR2(32),	-- "allowed" or "denied"
221
	perm_order	VARCHAR2(32),	-- "allow first" or "deny first"
222
	begin_time	DATE,		-- the time that permission begins
223
	end_time	DATE,		-- the time that permission ends
224
	ticket_count	NUMBER(5),	-- ticket counter for that permission
225
  subtreeid VARCHAR2(32), -- sub tree id
226
  startnodeid NUMBER(20), -- start node for sub tree
227
  endnodeid NUMBER(20),    -- end node for sub tree
228
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
229
   CONSTRAINT xml_access_accessfileid_fk 
230
		FOREIGN KEY (accessfileid) REFERENCES xml_documents
231
);
232

    
233
/* 
234
 * Index of Nodes -- table to store precomputed paths through tree for 
235
 * quick searching in structured searches
236
 */
237
CREATE TABLE xml_index (
238
	nodeid		NUMBER(20),	-- the unique node id
239
	path		VARCHAR2(200),	-- precomputed path through tree
240
	docid		VARCHAR2(250),	-- index to the document id
241
	doctype		VARCHAR2(100),	-- public id indicating document type
242
        parentnodeid    NUMBER(20),     -- id of the parent of the node 
243
					-- represented by this row
244
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
245
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
246
   CONSTRAINT xml_index_docid_fk 
247
		FOREIGN KEY (docid) REFERENCES xml_documents
248
);
249

    
250
/* 
251
 * Index of the paths in xml_index 
252
 */
253
CREATE INDEX xml_index_idx1 ON xml_index (path);
254

    
255
CREATE TABLE xml_relation (
256
	relationid    NUMBER(20) PRIMARY KEY, -- unique id
257
	docid         VARCHAR2(250),          -- the docid of the package file
258
	                                      -- that this relation came from
259
        packagetype   VARCHAR2(250),          -- the type of the package
260
	subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
261
	subdoctype    VARCHAR2(128),          -- the doctype of the subject
262
	relationship  VARCHAR2(128)  NOT NULL,-- the relationship type
263
	object        VARCHAR2(512) NOT NULL, -- the object of the relation
264
	objdoctype    VARCHAR2(128),          -- the doctype of the object
265
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
266
	CONSTRAINT xml_relation_docid_fk 
267
		FOREIGN KEY (docid) REFERENCES xml_documents
268
  );
269

    
270
CREATE SEQUENCE xml_relation_id_seq;
271
  
272
CREATE TRIGGER xml_relation_before_insert
273
BEFORE INSERT ON xml_relation FOR EACH ROW
274
BEGIN
275
  SELECT xml_relation_id_seq.nextval
276
    INTO :new.relationid
277
    FROM dual;
278
END;                                   
279
/
280

    
281
/* 
282
 * Table used as Unique ID generator for the uniqueid part of Accession#
283
 */
284
CREATE SEQUENCE accession_number_id_seq;
285
CREATE TABLE accession_number (
286
	uniqueid	NUMBER(20) PRIMARY KEY,
287
	site_code	VARCHAR2(100),
288
	date_created	DATE
289
);
290
CREATE TRIGGER accession_number_before_insert
291
BEFORE INSERT ON accession_number FOR EACH ROW
292
BEGIN
293
  SELECT accession_number_id_seq.nextval
294
    INTO :new.uniqueid
295
    FROM dual;
296
END;                                   
297
/
298

    
299
/* 
300
 * accesssubtree -- table to store access subtree info 
301
 */
302
CREATE TABLE xml_accesssubtree (
303
	docid		VARCHAR2(250),	-- the document id #
304
  rev 		NUMBER(10) DEFAULT 1, --the revision number of the docume
305
  controllevel VARCHAR2(50), -- the level it control -- document or subtree
306
  subtreeid VARCHAR2(250), -- the subtree id 
307
	startnodeid	NUMBER(20),	-- the start node id of access subtree
308
  endnodeid NUMBER(20) -- the end node if of access subtree
309
);
310

    
(17-17/18)