Project

General

Profile

1 741 harris
/*
2 755 bojilova
 * xmltables-postgres.sql
3
 *             : Create or replace tables for storing XML in PostgreSQL
4 741 harris
 *
5 755 bojilova
 *      Purpose: creates tables needed for storing XML in PostgreSQL database
6 741 harris
 *
7
 *      Created: 08 May 2001
8
 *       Author: John Harris
9
 * Organization: National Center for Ecological Analysis and Synthesis
10
 *    Copyright: 2000 Regents of the University of California and the
11
 *               National Center for Ecological Analysis and Synthesis
12 755 bojilova
 *  For Details: http://www.nceas.ucsb.edu/
13
 *    File Info: '$Id$'
14 741 harris
 *
15
 *	this is sql script does the same as the sql script named
16
 *	xmltables.sql except that this script is to be use to
17
 *	create the database tables on a Postgresql backend rather
18
 *	than an Oracle Backend
19
 */
20
21
/*
22
 * Drop all of the objects in proper order
23
 */
24
25
DROP SEQUENCE xml_nodes_id_seq;
26
DROP SEQUENCE xml_revisions_id_seq;
27
DROP SEQUENCE xml_catalog_id_seq;
28
DROP SEQUENCE xml_relation_id_seq;
29
DROP SEQUENCE xml_replication_id_seq;
30 749 bojilova
DROP SEQUENCE xml_documents_id_seq;
31 759 bojilova
DROP SEQUENCE accession_number_id_seq;
32 2096 jones
DROP SEQUENCE access_log_id_seq;
33 741 harris
34
DROP TABLE xml_index;
35
DROP TABLE xml_access;
36 1589 tao
DROP TABLE xml_accesssubtree;
37 741 harris
DROP TABLE xml_revisions;
38
DROP TABLE xml_relation;
39
DROP TABLE xml_documents;
40
DROP TABLE xml_nodes;
41
DROP TABLE xml_replication;
42
DROP TABLE xml_catalog;
43 759 bojilova
DROP TABLE accession_number;
44 2096 jones
DROP TABLE access_log;
45 741 harris
46
/*
47
 *Replication -- table to store servers that metacat is replicated to
48
 */
49
CREATE SEQUENCE xml_replication_id_seq;
50
CREATE TABLE xml_replication (
51 898 berkley
  serverid INT8 default nextval('xml_replication_id_seq'),
52
  server VARCHAR(512),
53
  last_checked DATE,
54 1292 tao
  replicate INT8,
55
  datareplicate INT8,
56
  hub INT8,
57 741 harris
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
58
);
59
60 1292 tao
INSERT INTO xml_replication (server, replicate, datareplicate, hub) VALUES ('localhost', '0', '0', '0');
61 741 harris
62
/*
63
 * Nodes -- table to store XML Nodes (both elements and attributes)
64
 */
65 759 bojilova
CREATE SEQUENCE xml_nodes_id_seq;
66 741 harris
CREATE TABLE xml_nodes (
67 898 berkley
	nodeid INT8 default nextval('xml_nodes_id_seq'),
68 759 bojilova
					-- the unique node id (pk)
69 898 berkley
	nodeindex INT8,		-- order of nodes within parent
70
	nodetype VARCHAR(20),	-- type (DOCUMENT, COMMENT, PI,
71 741 harris
					-- ELEMENT, ATTRIBUTE, TEXT)
72 898 berkley
	nodename VARCHAR(250),	-- the name of an element or attribute
73
        nodeprefix VARCHAR(50), -- the namespace prefix of the node
74
	nodedata VARCHAR(4000), 	-- the data for this node (e.g.,
75 741 harris
					-- for TEXT it is the content)
76 898 berkley
	parentnodeid INT8,		-- index of the parent of this node
77
	rootnodeid INT8,		-- index of the root node of this tree
78
	docid VARCHAR(250),	-- index to the document id
79
	date_created DATE,
80
	date_updated DATE,
81 741 harris
   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 759 bojilova
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
89 741 harris
 */
90
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
91
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
92 755 bojilova
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
93 741 harris
94
/*
95
 * XML Catalog -- table to store all external sources for XML documents
96
 */
97
CREATE SEQUENCE xml_catalog_id_seq;
98
CREATE TABLE xml_catalog (
99 898 berkley
	catalog_id INT8 default nextval('xml_catalog_id_seq'),
100 759 bojilova
                                        -- the id for this catalog entry
101 898 berkley
	entry_type VARCHAR(500),	-- the type of this catalog entry
102 741 harris
					-- (e.g., DTD, XSD, XSL)
103 898 berkley
	source_doctype VARCHAR(500),	-- the source public_id for transforms
104
	target_doctype VARCHAR(500),	-- the target public_id for transforms
105
	public_id VARCHAR(500),	-- the unique id for this type
106
	system_id VARCHAR(1000),	-- the local location of the object
107 741 harris
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
108 759 bojilova
   CONSTRAINT xml_catalog_uk UNIQUE
109
              (entry_type, source_doctype, target_doctype, public_id)
110 741 harris
);
111
112
/*
113 749 bojilova
 * Sequence to get uniqueID for Accession #
114
 */
115
CREATE SEQUENCE xml_documents_id_seq;
116
/*
117 741 harris
 * Documents -- table to store XML documents
118
 */
119
CREATE TABLE xml_documents (
120 898 berkley
	docid VARCHAR(250),	-- the document id #
121
	rootnodeid INT8,		-- reference to root node of the DOM
122
	docname VARCHAR(100),	-- usually the root element name
123
	doctype VARCHAR(100),	-- public id indicating document type
124
	user_owner VARCHAR(100),	-- the user owned the document
125
	user_updated VARCHAR(100),	-- the user updated the document
126 741 harris
	server_location INT8,	-- the server on which this document resides
127 899 berkley
	rev INT8 default 1,   -- the revision number of the document
128 898 berkley
	date_created DATE,
129
	date_updated DATE,
130
	public_access INT8,	-- flag for public access
131
        catalog_id INT8,	-- reference to xml_catalog
132 741 harris
     CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
133
     CONSTRAINT xml_documents_rep_fk
134
     		FOREIGN KEY (server_location) REFERENCES xml_replication,
135
    CONSTRAINT xml_documents_root_fk
136
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
137
   CONSTRAINT xml_documents_catalog_fk
138
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
139
);
140
141
/*
142
 * Index of <docid,doctype> in xml_document
143
 */
144
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
145
146
/*
147
 * Revised Documents -- table to store XML documents saved after an UPDATE
148
 *                    or DELETE
149
 */
150
CREATE SEQUENCE xml_revisions_id_seq;
151
CREATE TABLE xml_revisions (
152 898 berkley
	revisionid INT8  default nextval('xml_revisions_id_seq'),
153 759 bojilova
                                        -- the revision number we are saving
154 898 berkley
	docid VARCHAR(250),	-- the document id #
155
	rootnodeid INT8,		-- reference to root node of the DOM
156
	docname VARCHAR(100),	-- usually the root element name
157
	doctype VARCHAR(100),	-- public id indicating document type
158
	user_owner VARCHAR(100),
159
	user_updated VARCHAR(100),
160 741 harris
	server_location INT8,
161 898 berkley
	rev INT8,
162
	date_created DATE,
163
	date_updated DATE,
164
	public_access INT8,	-- flag for public access
165
        catalog_id INT8,	-- reference to xml_catalog
166 741 harris
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
167
   CONSTRAINT xml_revisions_rep_fk
168
		FOREIGN KEY (server_location) REFERENCES xml_replication,
169
   CONSTRAINT xml_revisions_root_fk
170
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
171
   CONSTRAINT xml_revisions_catalog_fk
172
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
173
);
174
175
176
/*
177
 * ACL -- table to store ACL for XML documents by principals
178
 */
179
CREATE TABLE xml_access (
180 898 berkley
	docid VARCHAR(250),	-- the document id #
181
	accessfileid VARCHAR(250),	-- the document id # for the access file
182
	principal_name VARCHAR(100),	-- name of user, group, etc.
183
	permission INT8,		-- "read", "write", "all"
184
	perm_type VARCHAR(32),	-- "allowed" or "denied"
185
	perm_order VARCHAR(32),	-- "allow first" or "deny first"
186
	begin_time DATE,		-- the time that permission begins
187
	end_time DATE,		-- the time that permission ends
188
	ticket_count INT8,		-- ticket counter for that permission
189 1421 tao
  subtreeid VARCHAR(32),
190
  startnodeid INT8,
191
  endnodeid INT8,
192 741 harris
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
193
   CONSTRAINT xml_access_accessfileid_fk
194
		FOREIGN KEY (accessfileid) REFERENCES xml_documents
195
);
196
197
/*
198
 * Index of Nodes -- table to store precomputed paths through tree for
199
 * quick searching in structured searches
200
 */
201
CREATE TABLE xml_index (
202 898 berkley
	nodeid INT8,		-- the unique node id
203
	path VARCHAR(200),	-- precomputed path through tree
204
	docid VARCHAR(250),	-- index to the document id
205
	doctype VARCHAR(100),	-- public id indicating document type
206
        parentnodeid INT8,     -- id of the parent of the node represented
207 741 harris
					-- by this row
208
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
209
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
210
   CONSTRAINT xml_index_docid_fk
211
		FOREIGN KEY (docid) REFERENCES xml_documents
212
);
213
214
/*
215
 * Index of the paths in xml_index
216
 */
217
CREATE INDEX xml_index_idx1 ON xml_index (path);
218
219 749 bojilova
220 741 harris
CREATE SEQUENCE xml_relation_id_seq;
221
CREATE TABLE xml_relation (
222 898 berkley
	relationid INT8 default nextval('xml_relation_id_seq') PRIMARY KEY,
223 759 bojilova
					     -- unique id
224 898 berkley
	docid VARCHAR(250) ,         -- the docid of the package file
225 759 bojilova
	                                     -- that this relation came from
226 898 berkley
        packagetype VARCHAR(250),          -- the type of the package
227
	subject VARCHAR(512) NOT NULL, -- the subject of the relation
228
	subdoctype VARCHAR(128),         	-- the doctype of the subject
229
	relationship VARCHAR(128)  NOT NULL,-- the relationship type
230
	object VARCHAR(512) NOT NULL, -- the object of the relation
231
	objdoctype VARCHAR(128),          -- the doctype of the object
232 1605 tao
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
233 741 harris
	CONSTRAINT xml_relation_docid_fk
234
		FOREIGN KEY (docid) REFERENCES xml_documents
235 898 berkley
);
236 741 harris
237 759 bojilova
/*
238
 * Table used as Unique ID generator for the uniqueid part of Accession#
239
 */
240
CREATE SEQUENCE accession_number_id_seq;
241
CREATE TABLE accession_number (
242 898 berkley
   uniqueid INT8 default nextval('accession_number_id_seq') PRIMARY KEY,
243
   site_code VARCHAR(100),
244
   date_created DATE
245 759 bojilova
);
246 741 harris
247 1531 tao
/*
248 1589 tao
 * accesssubtree -- table to store access subtree info
249 1531 tao
 */
250
CREATE TABLE xml_accesssubtree (
251
	docid		VARCHAR(250),	-- the document id #
252
  rev 		INT8 default 1, --the revision number of the docume
253
  controllevel VARCHAR(50), -- the level it control -- document or subtree
254
  subtreeid VARCHAR(250), -- the subtree id
255
	startnodeid	INT8,	-- the start node id of access subtree
256 1620 tao
  endnodeid INT8, -- the end node if of access subtree
257
  CONSTRAINT xml_accesssubtree_docid_fk
258
		FOREIGN KEY (docid) REFERENCES xml_documents
259 1531 tao
);
260 759 bojilova
261 2096 jones
/*
262
 *Logging -- table to store metadata and data access log
263
 */
264
CREATE SEQUENCE access_log_id_seq;
265
CREATE TABLE access_log (
266
  entryid       INT8 default nextval ('access_log_id_seq'),
267
  ip_address    VARCHAR(512),
268
  principal     VARCHAR(512),
269
  docid         VARCHAR(250),	-- the document id #
270
  rev           INT8,           -- the revision number
271
  event         VARCHAR(512),
272
  date_logged   TIMESTAMP,
273
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
274
);