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 472 2000-09-27 20:10:10Z 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

    
26
DROP TRIGGER xml_revisions_before_insert;
27
DROP TRIGGER xml_catalog_before_insert;
28
DROP TRIGGER xml_relation_before_insert;
29

    
30
DROP INDEX xml_relation_index;
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

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

    
64
/* 
65
 * Indexes of rootnodeid & parentnodeid in xml_nodes
66
 */
67
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
68
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
69

    
70
CREATE SEQUENCE xml_nodes_id_seq;
71

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

    
91
/* 
92
 * Index of <docid,doctype> in xml_document
93
 */
94
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
95

    
96
/* 
97
 * ACL -- table to store ACL for XML documents by principals
98
 */
99
CREATE TABLE xml_access (
100
	docid		VARCHAR2(250),	-- the document id #
101
	principal_name	VARCHAR2(100),	-- name of user, user group, etc.
102
	principal_type	VARCHAR2(20),	-- like "user", "group", etc.
103
	access_type	NUMBER(1),	-- "read", "write", "all"
104
	begin_time	DATE,		-- the time that access permission begins
105
	end_time	DATE,		-- the time that access permission ends
106
   CONSTRAINT xml_access_pk UNIQUE (docid, principal_name, principal_type, access_type, begin_time),
107
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time)
108
);
109

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

    
130
CREATE SEQUENCE xml_revisions_id_seq;
131

    
132
CREATE TRIGGER xml_revisions_before_insert
133
BEFORE INSERT ON xml_revisions FOR EACH ROW
134
BEGIN
135
  SELECT xml_revisions_id_seq.nextval
136
    INTO :new.revisionid
137
    FROM dual;
138
END;
139
/
140

    
141
/* 
142
 * XML Catalog -- table to store all external sources for XML documents
143
 */
144
CREATE TABLE xml_catalog (
145
	catalog_id	NUMBER(20),	-- the id for this catalog entry
146
	entry_type	VARCHAR2(500),	-- the type of this catalog entry
147
					-- (e.g., DTD, XSD, XSL)
148
	source_doctype	VARCHAR2(500),	-- the source public_id for transforms
149
	target_doctype	VARCHAR2(500),	-- the target public_id for transforms
150
	public_id	VARCHAR2(500),	-- the unique id for this type
151
	system_id	VARCHAR2(1000),	-- the local location of the object
152
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id)
153
   -- CONSTRAINT xml_catalog_uk UNIQUE (entry_type, source_doctype, target_doctype, public_id)
154
);
155

    
156
CREATE SEQUENCE xml_catalog_id_seq;
157

    
158
CREATE TRIGGER xml_catalog_before_insert
159
BEFORE INSERT ON xml_catalog FOR EACH ROW
160
BEGIN
161
  SELECT xml_catalog_id_seq.nextval
162
    INTO :new.catalog_id
163
    FROM dual;
164
END;
165
/
166

    
167
/* 
168
 * Index of Nodes -- table to store precomputed paths through tree for 
169
 * quick searching in structured searches
170
 */
171
CREATE TABLE xml_index (
172
	nodeid		NUMBER(20),	-- the unique node id
173
	path		VARCHAR2(200),	-- precomputed path through tree
174
	docid		VARCHAR2(250),	-- index to the document id
175
	doctype		VARCHAR2(100),	-- public id indicating document type
176
        parentnodeid    NUMBER(20),     -- id of the parent of the node represented by this row
177
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
178
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
179
   CONSTRAINT xml_index_docid_fk 
180
		FOREIGN KEY (docid) REFERENCES xml_documents
181
);
182

    
183
/* 
184
 * Index of the paths in xml_index 
185
 */
186
CREATE INDEX xml_index_idx1 ON xml_index (path);
187

    
188
/* 
189
 * table to store unique Accession # for every document in 2 parts
190
 */
191
CREATE TABLE xml_acc_numbers (
192
	global_name	VARCHAR2(32),	-- first part of acc #
193
	local_id	NUMBER(20),	-- second part - unique in global name
194
   CONSTRAINT xml_acc_numbers_pk PRIMARY KEY (global_name, local_id)
195
);
196

    
197
CREATE TABLE xml_relation (
198
  relationid    NUMBER(20) PRIMARY KEY,  -- unique id
199
  subject       VARCHAR2(1024) NOT NULL, -- the subject of the relation
200
  subdoctype    VARCHAR2(256),           -- the doctype of the subject
201
  relationship  VARCHAR2(512)  NOT NULL, -- the relationship type
202
  object        VARCHAR2(1024) NOT NULL, -- the object of the relation
203
  objdoctype    VARCHAR2(256)            -- the doctype of the object
204
  );
205
CREATE UNIQUE INDEX xml_relation_index
206
       ON xml_relation(relationid, subject, relationship, object);
207

    
208
CREATE SEQUENCE xml_relation_id_seq;
209
  
210
CREATE TRIGGER xml_relation_before_insert
211
BEFORE INSERT ON xml_relation FOR EACH ROW
212
BEGIN
213
  SELECT xml_relation_id_seq.nextval
214
    INTO :new.relationid
215
    FROM dual;
216
END;
217
/
218

    
(10-10/10)