Project

General

Profile

1
/*
2
 * xmltables-postgres.sql
3
 *             : Create or replace tables for storing XML in PostgreSQL
4
 *
5
 *      Purpose: creates tables needed for storing XML in PostgreSQL database
6
 * 
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
 *  For Details: http://www.nceas.ucsb.edu/
13
 *    File Info: '$Id: xmltables_postgres.sql 899 2002-01-18 18:24:13Z berkley $'
14
 *
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
DROP SEQUENCE xml_documents_id_seq;
31
DROP SEQUENCE accession_number_id_seq;
32

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

    
43
/*
44
 *Replication -- table to store servers that metacat is replicated to
45
 */
46
CREATE SEQUENCE xml_replication_id_seq;
47
CREATE TABLE xml_replication (
48
  serverid INT8 default nextval('xml_replication_id_seq'), 
49
  server VARCHAR(512),
50
  last_checked DATE,
51
  replicate INT8, 
52
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
53
);  
54

    
55
INSERT INTO xml_replication (serverid, server, replicate) VALUES ('1', 'localhost', '0');
56

    
57
/* 
58
 * Nodes -- table to store XML Nodes (both elements and attributes)
59
 */
60
CREATE SEQUENCE xml_nodes_id_seq;
61
CREATE TABLE xml_nodes (
62
	nodeid INT8 default nextval('xml_nodes_id_seq'),
63
					-- the unique node id (pk)
64
	nodeindex INT8,		-- order of nodes within parent
65
	nodetype VARCHAR(20),	-- type (DOCUMENT, COMMENT, PI,
66
					-- ELEMENT, ATTRIBUTE, TEXT)
67
	nodename VARCHAR(250),	-- the name of an element or attribute
68
        nodeprefix VARCHAR(50), -- the namespace prefix of the node
69
	nodedata VARCHAR(4000), 	-- the data for this node (e.g., 
70
					-- for TEXT it is the content)
71
	parentnodeid INT8,		-- index of the parent of this node
72
	rootnodeid INT8,		-- index of the root node of this tree
73
	docid VARCHAR(250),	-- index to the document id
74
	date_created DATE,
75
	date_updated DATE,
76
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
77
   CONSTRAINT xml_nodes_root_fk 
78
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
79
   CONSTRAINT xml_nodes_parent_fk 
80
		FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
81
);
82
/* 
83
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
84
 */
85
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
86
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
87
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
88

    
89
/* 
90
 * XML Catalog -- table to store all external sources for XML documents
91
 */
92
CREATE SEQUENCE xml_catalog_id_seq;
93
CREATE TABLE xml_catalog (
94
	catalog_id INT8 default nextval('xml_catalog_id_seq'),
95
                                        -- the id for this catalog entry
96
	entry_type VARCHAR(500),	-- the type of this catalog entry
97
					-- (e.g., DTD, XSD, XSL)
98
	source_doctype VARCHAR(500),	-- the source public_id for transforms
99
	target_doctype VARCHAR(500),	-- the target public_id for transforms
100
	public_id VARCHAR(500),	-- the unique id for this type
101
	system_id VARCHAR(1000),	-- the local location of the object
102
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
103
   CONSTRAINT xml_catalog_uk UNIQUE  
104
              (entry_type, source_doctype, target_doctype, public_id)
105
);
106

    
107
/* 
108
 * Sequence to get uniqueID for Accession #
109
 */
110
CREATE SEQUENCE xml_documents_id_seq;
111
/* 
112
 * Documents -- table to store XML documents
113
 */
114
CREATE TABLE xml_documents (
115
	docid VARCHAR(250),	-- the document id #
116
	rootnodeid INT8,		-- reference to root node of the DOM
117
	docname VARCHAR(100),	-- usually the root element name
118
	doctype VARCHAR(100),	-- public id indicating document type
119
	user_owner VARCHAR(100),	-- the user owned the document
120
	user_updated VARCHAR(100),	-- the user updated the document
121
	server_location INT8,	-- the server on which this document resides
122
	rev INT8 default 1,   -- the revision number of the document
123
	date_created DATE,
124
	date_updated DATE,
125
	public_access INT8,	-- flag for public access
126
        catalog_id INT8,	-- reference to xml_catalog 
127
     CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
128
     CONSTRAINT xml_documents_rep_fk
129
     		FOREIGN KEY (server_location) REFERENCES xml_replication, 
130
    CONSTRAINT xml_documents_root_fk 
131
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
132
   CONSTRAINT xml_documents_catalog_fk 
133
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
134
);
135

    
136
/* 
137
 * Index of <docid,doctype> in xml_document
138
 */
139
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
140

    
141
/* 
142
 * Revised Documents -- table to store XML documents saved after an UPDATE
143
 *                    or DELETE
144
 */
145
CREATE SEQUENCE xml_revisions_id_seq;
146
CREATE TABLE xml_revisions (
147
	revisionid INT8  default nextval('xml_revisions_id_seq'),
148
                                        -- the revision number we are saving
149
	docid VARCHAR(250),	-- the document id #
150
	rootnodeid INT8,		-- reference to root node of the DOM
151
	docname VARCHAR(100),	-- usually the root element name
152
	doctype VARCHAR(100),	-- public id indicating document type
153
	user_owner VARCHAR(100),
154
	user_updated VARCHAR(100),
155
	server_location INT8,
156
	rev INT8,
157
	date_created DATE,
158
	date_updated DATE,
159
	public_access INT8,	-- flag for public access
160
        catalog_id INT8,	-- reference to xml_catalog 
161
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
162
   CONSTRAINT xml_revisions_rep_fk
163
		FOREIGN KEY (server_location) REFERENCES xml_replication,
164
   CONSTRAINT xml_revisions_root_fk 
165
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
166
   CONSTRAINT xml_revisions_catalog_fk 
167
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
168
);
169

    
170

    
171
/* 
172
 * ACL -- table to store ACL for XML documents by principals
173
 */
174
CREATE TABLE xml_access (
175
	docid VARCHAR(250),	-- the document id #
176
	accessfileid VARCHAR(250),	-- the document id # for the access file
177
	principal_name VARCHAR(100),	-- name of user, group, etc.
178
	permission INT8,		-- "read", "write", "all"
179
	perm_type VARCHAR(32),	-- "allowed" or "denied"
180
	perm_order VARCHAR(32),	-- "allow first" or "deny first"
181
	begin_time DATE,		-- the time that permission begins
182
	end_time DATE,		-- the time that permission ends
183
	ticket_count INT8,		-- ticket counter for that permission
184
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
185
   CONSTRAINT xml_access_accessfileid_fk 
186
		FOREIGN KEY (accessfileid) REFERENCES xml_documents
187
);
188

    
189
/* 
190
 * Index of Nodes -- table to store precomputed paths through tree for 
191
 * quick searching in structured searches
192
 */
193
CREATE TABLE xml_index (
194
	nodeid INT8,		-- the unique node id
195
	path VARCHAR(200),	-- precomputed path through tree
196
	docid VARCHAR(250),	-- index to the document id
197
	doctype VARCHAR(100),	-- public id indicating document type
198
        parentnodeid INT8,     -- id of the parent of the node represented
199
					-- by this row
200
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
201
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
202
   CONSTRAINT xml_index_docid_fk 
203
		FOREIGN KEY (docid) REFERENCES xml_documents
204
);
205

    
206
/* 
207
 * Index of the paths in xml_index 
208
 */
209
CREATE INDEX xml_index_idx1 ON xml_index (path);
210

    
211

    
212
CREATE SEQUENCE xml_relation_id_seq;
213
CREATE TABLE xml_relation (
214
	relationid INT8 default nextval('xml_relation_id_seq') PRIMARY KEY,
215
					     -- unique id
216
	docid VARCHAR(250) ,         -- the docid of the package file
217
	                                     -- that this relation came from
218
        packagetype VARCHAR(250),          -- the type of the package
219
	subject VARCHAR(512) NOT NULL, -- the subject of the relation
220
	subdoctype VARCHAR(128),         	-- the doctype of the subject
221
	relationship VARCHAR(128)  NOT NULL,-- the relationship type
222
	object VARCHAR(512) NOT NULL, -- the object of the relation
223
	objdoctype VARCHAR(128),          -- the doctype of the object
224
	CONSTRAINT xml_relation_uk UNIQUE (subject, relationship, object),
225
	CONSTRAINT xml_relation_docid_fk 
226
		FOREIGN KEY (docid) REFERENCES xml_documents
227
);
228

    
229
/* 
230
 * Table used as Unique ID generator for the uniqueid part of Accession#
231
 */
232
CREATE SEQUENCE accession_number_id_seq;
233
CREATE TABLE accession_number (
234
   uniqueid INT8 default nextval('accession_number_id_seq') PRIMARY KEY,
235
   site_code VARCHAR(100),
236
   date_created DATE
237
);
238

    
239

    
240

    
(12-12/12)