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 749 2001-05-23 22:28:34Z bojilova $'
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

    
29
DROP TRIGGER xml_revisions_before_insert;
30
DROP TRIGGER xml_catalog_before_insert;
31
DROP TRIGGER xml_relation_before_insert;
32
DROP TRIGGER xml_replication_before_insert;
33

    
34
DROP TABLE xml_index;
35
DROP TABLE xml_access;
36
DROP TABLE xml_revisions;
37
DROP TABLE xml_relation;
38
DROP TABLE xml_documents;
39
DROP TABLE xml_nodes;
40
DROP TABLE xml_replication;
41
DROP TABLE xml_catalog;
42

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

    
64
INSERT INTO xml_replication (serverid, server, replicate) VALUES ('1', 'localhost', '0');
65

    
66
/* 
67
 * Nodes -- table to store XML Nodes (both elements and attributes)
68
 */
69
CREATE TABLE xml_nodes (
70
	nodeid		NUMBER(20),	-- the unique node id (pk)
71
	nodeindex	NUMBER(10),	-- order of nodes within parent
72
	nodetype	VARCHAR2(20),	-- type (DOCUMENT, COMMENT, PI,
73
					-- ELEMENT, ATTRIBUTE, TEXT)
74
	nodename	VARCHAR2(250),	-- the name of an element or attribute
75
	nodedata	VARCHAR2(4000), -- the data for this node (e.g., 
76
					-- for TEXT it is the content)
77
	parentnodeid	NUMBER(20),	-- index of the parent of this node
78
	rootnodeid	NUMBER(20),	-- index of the root node of this tree
79
	docid		VARCHAR2(250),	-- index to the document id
80
	date_created	DATE,
81
	date_updated	DATE,
82
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
83
   CONSTRAINT xml_nodes_root_fk 
84
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
85
   CONSTRAINT xml_nodes_parent_fk 
86
		FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
87
);
88

    
89
/* 
90
 * Indexes of rootnodeid & parentnodeid in xml_nodes
91
 */
92
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
93
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
94

    
95
CREATE SEQUENCE xml_nodes_id_seq;
96

    
97
/* 
98
 * XML Catalog -- table to store all external sources for XML documents
99
 */
100
CREATE TABLE xml_catalog (
101
	catalog_id	NUMBER(20),	-- the id for this catalog entry
102
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
103
					-- (e.g., DTD, XSD, XSL)
104
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
105
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
106
	public_id	VARCHAR2(500),	-- the unique id for this type
107
	system_id	VARCHAR2(1000),	-- the local location of the object
108
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
109
   CONSTRAINT xml_catalog_uk UNIQUE 
110
		(entry_type, source_doctype, target_doctype, public_id)
111
);
112

    
113
CREATE SEQUENCE xml_catalog_id_seq;
114

    
115
CREATE TRIGGER xml_catalog_before_insert
116
BEFORE INSERT ON xml_catalog FOR EACH ROW
117
BEGIN
118
  SELECT xml_catalog_id_seq.nextval
119
    INTO :new.catalog_id
120
    FROM dual;
121
END;
122
/
123

    
124
/* 
125
 * Documents -- table to store XML documents
126
 */
127
CREATE TABLE xml_documents (
128
	docid		VARCHAR2(250),	-- the document id #
129
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
130
	docname		VARCHAR2(100),	-- usually the root element name
131
	doctype		VARCHAR2(100),	-- public id indicating document type
132
	user_owner	VARCHAR2(100),	-- the user owned the document
133
	user_updated	VARCHAR2(100),	-- the user updated the document
134
	server_location NUMBER(20),	-- the server on which this document resides
135
	rev 		NUMBER(10) DEFAULT 1,--the revision number of the document
136
	date_created	DATE,
137
	date_updated	DATE,
138
	public_access	NUMBER(1),	-- flag for public access
139
        catalog_id      NUMBER(20),	-- reference to xml_catalog 
140
   CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
141
   CONSTRAINT xml_documents_rep_fk
142
    		FOREIGN KEY (server_location) REFERENCES xml_replication, 
143
   CONSTRAINT xml_documents_root_fk 
144
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
145
   CONSTRAINT xml_documents_catalog_fk 
146
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
147
);
148

    
149
/* 
150
 * Sequence to get uniqueID for Accession #
151
 */
152
CREATE SEQUENCE xml_documents_id_seq;
153

    
154
/* 
155
 * Index of <docid,doctype> in xml_document
156
 */
157
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
158

    
159
/* 
160
 * Revised Documents -- table to store XML documents saved after an UPDATE
161
 *                    or DELETE
162
 */
163
CREATE TABLE xml_revisions (
164
	revisionid	NUMBER(20),	-- the revision number we are saving
165
	docid		VARCHAR2(250),	-- the document id #
166
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
167
	docname		VARCHAR2(100),	-- usually the root element name
168
	doctype		VARCHAR2(100),	-- public id indicating document type
169
	user_owner	VARCHAR2(100),
170
	user_updated	VARCHAR2(100),
171
	server_location NUMBER(20),
172
	rev		NUMBER(10),
173
	date_created	DATE,
174
	date_updated	DATE,
175
	public_access	NUMBER(1),	-- flag for public access
176
        catalog_id      NUMBER(20),	-- reference to xml_catalog 
177
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
178
   CONSTRAINT xml_revisions_rep_fk
179
		FOREIGN KEY (server_location) REFERENCES xml_replication,
180
   CONSTRAINT xml_revisions_root_fk 
181
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
182
   CONSTRAINT xml_revisions_catalog_fk 
183
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
184
);
185

    
186
CREATE SEQUENCE xml_revisions_id_seq;
187

    
188
CREATE TRIGGER xml_revisions_before_insert
189
BEFORE INSERT ON xml_revisions FOR EACH ROW
190
BEGIN
191
  SELECT xml_revisions_id_seq.nextval
192
    INTO :new.revisionid
193
    FROM dual;
194
END;
195
/
196

    
197
/* 
198
 * ACL -- table to store ACL for XML documents by principals
199
 */
200
CREATE TABLE xml_access (
201
	docid		VARCHAR2(250),	-- the document id #
202
	accessfileid	VARCHAR2(250),	-- the document id # for the access file
203
	principal_name	VARCHAR2(100),	-- name of user, group, etc.
204
	permission	NUMBER(1),	-- "read", "write", "all"
205
	perm_type	VARCHAR2(32),	-- "allowed" or "denied"
206
	perm_order	VARCHAR2(32),	-- "allow first" or "deny first"
207
	begin_time	DATE,		-- the time that permission begins
208
	end_time	DATE,		-- the time that permission ends
209
	ticket_count	NUMBER(5),	-- ticket counter for that permission
210
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
211
   CONSTRAINT xml_access_accessfileid_fk 
212
		FOREIGN KEY (accessfileid) REFERENCES xml_documents
213
);
214

    
215
/* 
216
 * Index of Nodes -- table to store precomputed paths through tree for 
217
 * quick searching in structured searches
218
 */
219
CREATE TABLE xml_index (
220
	nodeid		NUMBER(20),	-- the unique node id
221
	path		VARCHAR2(200),	-- precomputed path through tree
222
	docid		VARCHAR2(250),	-- index to the document id
223
	doctype		VARCHAR2(100),	-- public id indicating document type
224
        parentnodeid    NUMBER(20),     -- id of the parent of the node represented
225
					-- by this row
226
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
227
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
228
   CONSTRAINT xml_index_docid_fk 
229
		FOREIGN KEY (docid) REFERENCES xml_documents
230
);
231

    
232
/* 
233
 * Index of the paths in xml_index 
234
 */
235
CREATE INDEX xml_index_idx1 ON xml_index (path);
236

    
237
CREATE TABLE xml_relation (
238
	relationid    NUMBER(20) PRIMARY KEY, -- unique id
239
	docid         VARCHAR2(250),          -- the docid of the package file
240
	                                      -- that this relation came from
241
        packagetype   VARCHAR2(250),          -- the type of the package
242
	subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
243
	subdoctype    VARCHAR2(128),          -- the doctype of the subject
244
	relationship  VARCHAR2(128)  NOT NULL,-- the relationship type
245
	object        VARCHAR2(512) NOT NULL, -- the object of the relation
246
	objdoctype    VARCHAR2(128),          -- the doctype of the object
247
	CONSTRAINT xml_relation_uk UNIQUE (subject, relationship, object),
248
	CONSTRAINT xml_relation_docid_fk 
249
		FOREIGN KEY (docid) REFERENCES xml_documents
250
  );
251

    
252
CREATE SEQUENCE xml_relation_id_seq;
253
  
254
CREATE TRIGGER xml_relation_before_insert
255
BEFORE INSERT ON xml_relation FOR EACH ROW
256
BEGIN
257
  SELECT xml_relation_id_seq.nextval
258
    INTO :new.relationid
259
    FROM dual;
260
END;
261
/
262

    
(12-12/13)