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 1530 2003-04-09 01:14:56Z 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_revisions;
41
DROP TABLE xml_relation;
42
DROP TABLE xml_documents;
43
DROP TABLE xml_nodes;
44
DROP TABLE xml_replication;
45
DROP TABLE xml_catalog;
46
DROP TABLE accession_number;
47

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

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

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

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

    
131
CREATE SEQUENCE xml_catalog_id_seq;
132

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

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

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

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

    
200
CREATE SEQUENCE xml_revisions_id_seq;
201

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

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

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

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

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

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

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

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

    
(17-17/18)