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 616 2000-12-14 23:04:37Z 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

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

    
33
DROP TABLE xml_index;
34
DROP TABLE xml_catalog;
35
DROP TABLE xml_access;
36
DROP TABLE xml_revisions;
37
DROP TABLE xml_documents;
38
DROP TABLE xml_nodes;
39
DROP TABLE xml_acc_numbers;
40
DROP TABLE xml_relation;
41
DROP TABLE xml_replication;
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
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
51
);  
52
  
53
CREATE SEQUENCE xml_replication_id_seq;
54
CREATE TRIGGER xml_replication_before_insert
55
BEFORE INSERT ON xml_replication FOR EACH ROW
56
BEGIN
57
  SELECT xml_replication_id_seq.nextval
58
    INTO :new.serverid
59
    FROM dual;
60
END;
61
/
62

    
63
INSERT INTO xml_replication (serverid, server) VALUES ('1', 'localhost');
64

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

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

    
94
CREATE SEQUENCE xml_nodes_id_seq;
95

    
96
/* 
97
 * Documents -- table to store XML documents
98
 */
99
CREATE TABLE xml_documents (
100
	docid		VARCHAR2(250),	-- the document id #
101
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
102
	docname		VARCHAR2(100),	-- usually the root element name
103
	doctype		VARCHAR2(100),	-- public id indicating document type
104
	doctitle	VARCHAR2(1000),	-- title of document if exists
105
	user_owner	VARCHAR2(100),	-- the user owned the document
106
	user_updated	VARCHAR2(100),	-- the user updated the document
107
  server_location NUMBER(20), -- the server on which this document resides
108
  rev NUMBER(10) DEFAULT 1,  --the revision number of the document
109
	date_created	DATE,
110
	date_updated	DATE,
111
	public_access	NUMBER(1) DEFAULT 1, -- flag for public access
112
  updated NUMBER(1) DEFAULT 0,
113
   CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
114
   CONSTRAINT xml_documents_rep_fk
115
    FOREIGN KEY (server_location) REFERENCES xml_replication, 
116
   CONSTRAINT xml_documents_root_fk 
117
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes
118
);
119

    
120
/* 
121
 * Index of <docid,doctype> in xml_document
122
 */
123
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
124

    
125
/* 
126
 * ACL -- table to store ACL for XML documents by principals
127
 */
128
CREATE TABLE xml_access (
129
	docid		VARCHAR2(250),	-- the document id #
130
	principal_name	VARCHAR2(100),	-- name of user, group, etc.
131
	permission	NUMBER(1),	-- "read", "write", "all"
132
	perm_type	VARCHAR2(32),	-- "allowed" or "denied"
133
	perm_order	VARCHAR2(32),	-- "allow first" or "deny first"
134
	begin_time	DATE,		-- the time that permission begins
135
	end_time	DATE,		-- the time that permission ends
136
	ticket_count	NUMBER(5),	-- ticket counter for that permission
137
   CONSTRAINT xml_access_pk UNIQUE (docid, principal_name, permission, perm_type),
138
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time)
139
);
140

    
141
/* 
142
 * Revised Documents -- table to store XML documents saved after an UPDATE
143
 *                    or DELETE
144
 */
145
CREATE TABLE xml_revisions (
146
	revisionid	NUMBER(20),	-- the revision number we are saving
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
	doctitle	VARCHAR2(1000),	-- title of document if exists
152
	user_owner	VARCHAR2(100),
153
	user_updated	VARCHAR2(100),
154
	server_location NUMBER(20),
155
  rev NUMBER(10),
156
	date_created	DATE,
157
	date_updated	DATE,
158
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
159
   CONSTRAINT xml_revisions_rep_fk
160
    FOREIGN KEY (server_location) REFERENCES xml_replication,
161
   CONSTRAINT xml_revisions_root_fk 
162
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes
163
);
164

    
165
CREATE SEQUENCE xml_revisions_id_seq;
166

    
167
CREATE TRIGGER xml_revisions_before_insert
168
BEFORE INSERT ON xml_revisions FOR EACH ROW
169
BEGIN
170
  SELECT xml_revisions_id_seq.nextval
171
    INTO :new.revisionid
172
    FROM dual;
173
END;
174
/
175

    
176
/* 
177
 * XML Catalog -- table to store all external sources for XML documents
178
 */
179
CREATE TABLE xml_catalog (
180
	catalog_id	NUMBER(20),	-- the id for this catalog entry
181
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
182
					-- (e.g., DTD, XSD, XSL)
183
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
184
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
185
	public_id	VARCHAR2(500),	-- the unique id for this type
186
	system_id	VARCHAR2(1000),	-- the local location of the object
187
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
188
   CONSTRAINT xml_catalog_uk UNIQUE (entry_type, source_doctype, target_doctype, public_id)
189
);
190

    
191
CREATE SEQUENCE xml_catalog_id_seq;
192

    
193
CREATE TRIGGER xml_catalog_before_insert
194
BEFORE INSERT ON xml_catalog FOR EACH ROW
195
BEGIN
196
  SELECT xml_catalog_id_seq.nextval
197
    INTO :new.catalog_id
198
    FROM dual;
199
END;
200
/
201

    
202
/* 
203
 * Index of Nodes -- table to store precomputed paths through tree for 
204
 * quick searching in structured searches
205
 */
206
CREATE TABLE xml_index (
207
	nodeid		NUMBER(20),	-- the unique node id
208
	path		VARCHAR2(200),	-- precomputed path through tree
209
	docid		VARCHAR2(250),	-- index to the document id
210
	doctype		VARCHAR2(100),	-- public id indicating document type
211
        parentnodeid    NUMBER(20),     -- id of the parent of the node represented by this row
212
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
213
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
214
   CONSTRAINT xml_index_docid_fk 
215
		FOREIGN KEY (docid) REFERENCES xml_documents
216
);
217

    
218
/* 
219
 * Index of the paths in xml_index 
220
 */
221
CREATE INDEX xml_index_idx1 ON xml_index (path);
222

    
223
/* 
224
 * Sequence to get uniqueID for Accession #
225
 */
226
CREATE SEQUENCE accnum_uniqueid_seq;
227

    
228
CREATE TABLE xml_relation (
229
  relationid    NUMBER(20) PRIMARY KEY,  -- unique id
230
  subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
231
  subdoctype    VARCHAR2(128),           -- the doctype of the subject
232
  relationship  VARCHAR2(128)  NOT NULL, -- the relationship type
233
  object        VARCHAR2(512) NOT NULL, -- the object of the relation
234
  objdoctype    VARCHAR2(128),            -- the doctype of the object
235
  CONSTRAINT xml_relation_unk UNIQUE (subject, relationship, object)
236
  );
237

    
238
CREATE SEQUENCE xml_relation_id_seq;
239
  
240
CREATE TRIGGER xml_relation_before_insert
241
BEFORE INSERT ON xml_relation FOR EACH ROW
242
BEGIN
243
  SELECT xml_relation_id_seq.nextval
244
    INTO :new.relationid
245
    FROM dual;
246
END;
247
/
248

    
(11-11/11)