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 544 2000-11-16 19:01:36Z berkley $'
|
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
|
|
27
|
DROP TRIGGER xml_revisions_before_insert;
|
28
|
DROP TRIGGER xml_catalog_before_insert;
|
29
|
DROP TRIGGER xml_relation_before_insert;
|
30
|
DROP TRIGGER xml_replication_before_insert;
|
31
|
|
32
|
DROP TABLE xml_index;
|
33
|
DROP TABLE xml_catalog;
|
34
|
DROP TABLE xml_access;
|
35
|
DROP TABLE xml_revisions;
|
36
|
DROP TABLE xml_documents;
|
37
|
DROP TABLE xml_nodes;
|
38
|
DROP TABLE xml_acc_numbers;
|
39
|
DROP TABLE xml_relation;
|
40
|
DROP TABLE xml_replication;
|
41
|
|
42
|
/*
|
43
|
*Replication -- table to store servers that metacat is replicated to
|
44
|
*/
|
45
|
CREATE TABLE xml_replication (
|
46
|
serverid NUMBER(20),
|
47
|
server VARCHAR2(512),
|
48
|
last_checked DATE,
|
49
|
CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
|
50
|
);
|
51
|
|
52
|
CREATE SEQUENCE xml_replication_id_seq;
|
53
|
CREATE TRIGGER xml_replication_before_insert
|
54
|
BEFORE INSERT ON xml_replication FOR EACH ROW
|
55
|
BEGIN
|
56
|
SELECT xml_replication_id_seq.nextval
|
57
|
INTO :new.serverid
|
58
|
FROM dual;
|
59
|
END;
|
60
|
/
|
61
|
|
62
|
/*
|
63
|
* Nodes -- table to store XML Nodes (both elements and attributes)
|
64
|
*/
|
65
|
CREATE TABLE xml_nodes (
|
66
|
nodeid NUMBER(20), -- the unique node id (pk)
|
67
|
nodeindex NUMBER(10), -- order of nodes within parent
|
68
|
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI,
|
69
|
-- ELEMENT, ATTRIBUTE, TEXT)
|
70
|
nodename VARCHAR2(250), -- the name of an element or attribute
|
71
|
nodedata VARCHAR2(4000), -- the data for this node (e.g.,
|
72
|
-- for TEXT it is the content)
|
73
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
74
|
rootnodeid NUMBER(20), -- index of the root node of this tree
|
75
|
docid VARCHAR2(250), -- index to the document id
|
76
|
date_created DATE,
|
77
|
date_updated DATE,
|
78
|
CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
|
79
|
CONSTRAINT xml_nodes_root_fk
|
80
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
|
81
|
CONSTRAINT xml_nodes_parent_fk
|
82
|
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
|
83
|
);
|
84
|
|
85
|
/*
|
86
|
* Indexes of rootnodeid & parentnodeid in xml_nodes
|
87
|
*/
|
88
|
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
|
89
|
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
|
90
|
|
91
|
CREATE SEQUENCE xml_nodes_id_seq;
|
92
|
|
93
|
/*
|
94
|
* Documents -- table to store XML documents
|
95
|
*/
|
96
|
CREATE TABLE xml_documents (
|
97
|
docid VARCHAR2(250), -- the document id #
|
98
|
rootnodeid NUMBER(20), -- reference to root node of the DOM
|
99
|
docname VARCHAR2(100), -- usually the root element name
|
100
|
doctype VARCHAR2(100), -- public id indicating document type
|
101
|
doctitle VARCHAR2(1000), -- title of document if exists
|
102
|
user_owner VARCHAR2(100), -- the user owned the document
|
103
|
user_updated VARCHAR2(100), -- the user updated the document
|
104
|
server_location NUMBER(20), -- the server on which this document resides
|
105
|
date_created DATE,
|
106
|
date_updated DATE,
|
107
|
public_access NUMBER(1) DEFAULT 1, -- flag for public access
|
108
|
CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
|
109
|
CONSTRAINT xml_documents_rep_fk
|
110
|
FOREIGN KEY (server_location) REFERENCES xml_replication,
|
111
|
CONSTRAINT xml_documents_root_fk
|
112
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes
|
113
|
);
|
114
|
|
115
|
/*
|
116
|
* Index of <docid,doctype> in xml_document
|
117
|
*/
|
118
|
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
|
119
|
|
120
|
/*
|
121
|
* ACL -- table to store ACL for XML documents by principals
|
122
|
*/
|
123
|
CREATE TABLE xml_access (
|
124
|
docid VARCHAR2(250), -- the document id #
|
125
|
principal_name VARCHAR2(100), -- name of user, user group, etc.
|
126
|
principal_type VARCHAR2(20), -- like "user", "group", etc.
|
127
|
access_type NUMBER(1), -- "read", "write", "all"
|
128
|
begin_time DATE, -- the time that access permission begins
|
129
|
end_time DATE, -- the time that access permission ends
|
130
|
CONSTRAINT xml_access_pk UNIQUE (docid, principal_name, principal_type, access_type, begin_time),
|
131
|
CONSTRAINT xml_access_ck CHECK (begin_time < end_time)
|
132
|
);
|
133
|
|
134
|
/*
|
135
|
* Revised Documents -- table to store XML documents saved after an UPDATE
|
136
|
* or DELETE
|
137
|
*/
|
138
|
CREATE TABLE xml_revisions (
|
139
|
revisionid NUMBER(20), -- the revision number we are saving
|
140
|
docid VARCHAR2(250), -- the document id #
|
141
|
rootnodeid NUMBER(20), -- reference to root node of the DOM
|
142
|
docname VARCHAR2(100), -- usually the root element name
|
143
|
doctype VARCHAR2(100), -- public id indicating document type
|
144
|
doctitle VARCHAR2(1000), -- title of document if exists
|
145
|
user_owner VARCHAR2(100),
|
146
|
user_updated VARCHAR2(100),
|
147
|
date_created DATE,
|
148
|
date_updated DATE,
|
149
|
CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
|
150
|
CONSTRAINT xml_revisions_root_fk
|
151
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes
|
152
|
);
|
153
|
|
154
|
CREATE SEQUENCE xml_revisions_id_seq;
|
155
|
|
156
|
CREATE TRIGGER xml_revisions_before_insert
|
157
|
BEFORE INSERT ON xml_revisions FOR EACH ROW
|
158
|
BEGIN
|
159
|
SELECT xml_revisions_id_seq.nextval
|
160
|
INTO :new.revisionid
|
161
|
FROM dual;
|
162
|
END;
|
163
|
/
|
164
|
|
165
|
/*
|
166
|
* XML Catalog -- table to store all external sources for XML documents
|
167
|
*/
|
168
|
CREATE TABLE xml_catalog (
|
169
|
catalog_id NUMBER(20), -- the id for this catalog entry
|
170
|
entry_type VARCHAR2(500), -- the type of this catalog entry
|
171
|
-- (e.g., DTD, XSD, XSL)
|
172
|
source_doctype VARCHAR2(500), -- the source public_id for transforms
|
173
|
target_doctype VARCHAR2(500), -- the target public_id for transforms
|
174
|
public_id VARCHAR2(500), -- the unique id for this type
|
175
|
system_id VARCHAR2(1000), -- the local location of the object
|
176
|
CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id)
|
177
|
-- CONSTRAINT xml_catalog_uk UNIQUE (entry_type, source_doctype, target_doctype, public_id)
|
178
|
);
|
179
|
|
180
|
CREATE SEQUENCE xml_catalog_id_seq;
|
181
|
|
182
|
CREATE TRIGGER xml_catalog_before_insert
|
183
|
BEFORE INSERT ON xml_catalog FOR EACH ROW
|
184
|
BEGIN
|
185
|
SELECT xml_catalog_id_seq.nextval
|
186
|
INTO :new.catalog_id
|
187
|
FROM dual;
|
188
|
END;
|
189
|
/
|
190
|
|
191
|
/*
|
192
|
* Index of Nodes -- table to store precomputed paths through tree for
|
193
|
* quick searching in structured searches
|
194
|
*/
|
195
|
CREATE TABLE xml_index (
|
196
|
nodeid NUMBER(20), -- the unique node id
|
197
|
path VARCHAR2(200), -- precomputed path through tree
|
198
|
docid VARCHAR2(250), -- index to the document id
|
199
|
doctype VARCHAR2(100), -- public id indicating document type
|
200
|
parentnodeid NUMBER(20), -- id of the parent of the node represented by this row
|
201
|
CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
|
202
|
CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
|
203
|
CONSTRAINT xml_index_docid_fk
|
204
|
FOREIGN KEY (docid) REFERENCES xml_documents
|
205
|
);
|
206
|
|
207
|
/*
|
208
|
* Index of the paths in xml_index
|
209
|
*/
|
210
|
CREATE INDEX xml_index_idx1 ON xml_index (path);
|
211
|
|
212
|
/*
|
213
|
* table to store unique Accession # for every document in 2 parts
|
214
|
*/
|
215
|
CREATE TABLE xml_acc_numbers (
|
216
|
global_name VARCHAR2(32), -- first part of acc #
|
217
|
local_id NUMBER(20), -- second part - unique in global name
|
218
|
CONSTRAINT xml_acc_numbers_pk PRIMARY KEY (global_name, local_id)
|
219
|
);
|
220
|
|
221
|
CREATE TABLE xml_relation (
|
222
|
relationid NUMBER(20) PRIMARY KEY, -- unique id
|
223
|
subject VARCHAR2(512) NOT NULL, -- the subject of the relation
|
224
|
subdoctype VARCHAR2(128), -- the doctype of the subject
|
225
|
relationship VARCHAR2(128) NOT NULL, -- the relationship type
|
226
|
object VARCHAR2(512) NOT NULL, -- the object of the relation
|
227
|
objdoctype VARCHAR2(128), -- the doctype of the object
|
228
|
CONSTRAINT xml_relation_unk UNIQUE (subject, relationship, object)
|
229
|
);
|
230
|
|
231
|
CREATE SEQUENCE xml_relation_id_seq;
|
232
|
|
233
|
CREATE TRIGGER xml_relation_before_insert
|
234
|
BEFORE INSERT ON xml_relation FOR EACH ROW
|
235
|
BEGIN
|
236
|
SELECT xml_relation_id_seq.nextval
|
237
|
INTO :new.relationid
|
238
|
FROM dual;
|
239
|
END;
|
240
|
/
|
241
|
|