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 517 2000-11-08 18:18:26Z 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 INDEX xml_relation_index;
33

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

    
44
/*
45
 *Replication -- table to store servers that metacat is replicated to
46
 */
47
CREATE TABLE xml_replication (
48
  server    VARCHAR2(512),
49
  last_checked  DATE);  
50

    
51
/* 
52
 * Nodes -- table to store XML Nodes (both elements and attributes)
53
 */
54
CREATE TABLE xml_nodes (
55
	nodeid		NUMBER(20),	-- the unique node id (pk)
56
	nodeindex	NUMBER(10),	-- order of nodes within parent
57
	nodetype	VARCHAR2(20),	-- type (DOCUMENT, COMMENT, PI,
58
					-- ELEMENT, ATTRIBUTE, TEXT)
59
	nodename	VARCHAR2(250),	-- the name of an element or attribute
60
	nodedata	VARCHAR2(4000), -- the data for this node (e.g., 
61
					-- for TEXT it is the content)
62
	parentnodeid	NUMBER(20),	-- index of the parent of this node
63
	rootnodeid	NUMBER(20),	-- index of the root node of this tree
64
	docid		VARCHAR2(250),	-- index to the document id
65
	date_created	DATE,
66
	date_updated	DATE,
67
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
68
   CONSTRAINT xml_nodes_root_fk 
69
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
70
   CONSTRAINT xml_nodes_parent_fk 
71
		FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
72
);
73

    
74
/* 
75
 * Indexes of rootnodeid & parentnodeid in xml_nodes
76
 */
77
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
78
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
79

    
80
CREATE SEQUENCE xml_nodes_id_seq;
81

    
82
/* 
83
 * Documents -- table to store XML documents
84
 */
85
CREATE TABLE xml_documents (
86
	docid		VARCHAR2(250),	-- the document id #
87
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
88
	docname		VARCHAR2(100),	-- usually the root element name
89
	doctype		VARCHAR2(100),	-- public id indicating document type
90
	doctitle	VARCHAR2(1000),	-- title of document if exists
91
	user_owner	VARCHAR2(100),	-- the user owned the document
92
	user_updated	VARCHAR2(100),	-- the user updated the document
93
	date_created	DATE,
94
	date_updated	DATE,
95
	public_access	NUMBER(1) DEFAULT 1, -- flag for public access
96
   CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
97
   CONSTRAINT xml_documents_root_fk 
98
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes
99
);
100

    
101
/* 
102
 * Index of <docid,doctype> in xml_document
103
 */
104
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
105

    
106
/* 
107
 * ACL -- table to store ACL for XML documents by principals
108
 */
109
CREATE TABLE xml_access (
110
	docid		VARCHAR2(250),	-- the document id #
111
	principal_name	VARCHAR2(100),	-- name of user, user group, etc.
112
	principal_type	VARCHAR2(20),	-- like "user", "group", etc.
113
	access_type	NUMBER(1),	-- "read", "write", "all"
114
	begin_time	DATE,		-- the time that access permission begins
115
	end_time	DATE,		-- the time that access permission ends
116
   CONSTRAINT xml_access_pk UNIQUE (docid, principal_name, principal_type, access_type, begin_time),
117
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time)
118
);
119

    
120
/* 
121
 * Revised Documents -- table to store XML documents saved after an UPDATE
122
 *                    or DELETE
123
 */
124
CREATE TABLE xml_revisions (
125
	revisionid	NUMBER(20),	-- the revision number we are saving
126
	docid		VARCHAR2(250),	-- the document id #
127
	rootnodeid	NUMBER(20),	-- reference to root node of the DOM
128
	docname		VARCHAR2(100),	-- usually the root element name
129
	doctype		VARCHAR2(100),	-- public id indicating document type
130
	doctitle	VARCHAR2(1000),	-- title of document if exists
131
	user_owner	VARCHAR2(100),
132
	user_updated	VARCHAR2(100),
133
	date_created	DATE,
134
	date_updated	DATE,
135
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
136
   CONSTRAINT xml_revisions_root_fk 
137
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes
138
);
139

    
140
CREATE SEQUENCE xml_revisions_id_seq;
141

    
142
CREATE TRIGGER xml_revisions_before_insert
143
BEFORE INSERT ON xml_revisions FOR EACH ROW
144
BEGIN
145
  SELECT xml_revisions_id_seq.nextval
146
    INTO :new.revisionid
147
    FROM dual;
148
END;
149
/
150

    
151
/* 
152
 * XML Catalog -- table to store all external sources for XML documents
153
 */
154
CREATE TABLE xml_catalog (
155
	catalog_id	NUMBER(20),	-- the id for this catalog entry
156
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
157
					-- (e.g., DTD, XSD, XSL)
158
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
159
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
160
	public_id	VARCHAR2(500),	-- the unique id for this type
161
	system_id	VARCHAR2(1000),	-- the local location of the object
162
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id)
163
   -- CONSTRAINT xml_catalog_uk UNIQUE (entry_type, source_doctype, target_doctype, public_id)
164
);
165

    
166
CREATE SEQUENCE xml_catalog_id_seq;
167

    
168
CREATE TRIGGER xml_catalog_before_insert
169
BEFORE INSERT ON xml_catalog FOR EACH ROW
170
BEGIN
171
  SELECT xml_catalog_id_seq.nextval
172
    INTO :new.catalog_id
173
    FROM dual;
174
END;
175
/
176

    
177
/* 
178
 * Index of Nodes -- table to store precomputed paths through tree for 
179
 * quick searching in structured searches
180
 */
181
CREATE TABLE xml_index (
182
	nodeid		NUMBER(20),	-- the unique node id
183
	path		VARCHAR2(200),	-- precomputed path through tree
184
	docid		VARCHAR2(250),	-- index to the document id
185
	doctype		VARCHAR2(100),	-- public id indicating document type
186
        parentnodeid    NUMBER(20),     -- id of the parent of the node represented by this row
187
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
188
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
189
   CONSTRAINT xml_index_docid_fk 
190
		FOREIGN KEY (docid) REFERENCES xml_documents
191
);
192

    
193
/* 
194
 * Index of the paths in xml_index 
195
 */
196
CREATE INDEX xml_index_idx1 ON xml_index (path);
197

    
198
/* 
199
 * table to store unique Accession # for every document in 2 parts
200
 */
201
CREATE TABLE xml_acc_numbers (
202
	global_name	VARCHAR2(32),	-- first part of acc #
203
	local_id	NUMBER(20),	-- second part - unique in global name
204
   CONSTRAINT xml_acc_numbers_pk PRIMARY KEY (global_name, local_id)
205
);
206

    
207
CREATE TABLE xml_relation (
208
  relationid    NUMBER(20) PRIMARY KEY,  -- unique id
209
  subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
210
  subdoctype    VARCHAR2(128),           -- the doctype of the subject
211
  relationship  VARCHAR2(128)  NOT NULL, -- the relationship type
212
  object        VARCHAR2(512) NOT NULL, -- the object of the relation
213
  objdoctype    VARCHAR2(128),            -- the doctype of the object
214
  CONSTRAINT xml_relation_unk UNIQUE (subject, relationship, object)
215
  );
216

    
217
CREATE SEQUENCE xml_relation_id_seq;
218
  
219
CREATE TRIGGER xml_relation_before_insert
220
BEFORE INSERT ON xml_relation FOR EACH ROW
221
BEGIN
222
  SELECT xml_relation_id_seq.nextval
223
    INTO :new.relationid
224
    FROM dual;
225
END;
226
/
227

    
(10-10/10)