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 759 2001-06-01 00:26:32Z bojilova $'
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
set echo off
25

    
26
DROP SEQUENCE xml_nodes_id_seq;
27
DROP SEQUENCE xml_revisions_id_seq;
28
DROP SEQUENCE xml_catalog_id_seq;
29
DROP SEQUENCE xml_relation_id_seq;
30
DROP SEQUENCE xml_replication_id_seq;
31
DROP SEQUENCE accnum_uniqueid_seq;
32
DROP SEQUENCE xml_documents_id_seq;
33
DROP SEQUENCE accession_number_id_seq;
34

    
35
DROP TABLE xml_index;
36
DROP TABLE xml_access;
37
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
DROP TABLE accession_number;
44

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

    
57
INSERT INTO xml_replication (serverid, server, replicate) VALUES ('1', 'localhost', '0');
58

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

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

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

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

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

    
171

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

    
190
/* 
191
 * Index of Nodes -- table to store precomputed paths through tree for 
192
 * quick searching in structured searches
193
 */
194
CREATE TABLE xml_index (
195
	nodeid		INT8,		-- the unique node id
196
	path		VARCHAR(200),	-- precomputed path through tree
197
	docid		VARCHAR(250),	-- index to the document id
198
	doctype		VARCHAR(100),	-- public id indicating document type
199
        parentnodeid    INT8,     -- id of the parent of the node represented
200
					-- 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
CREATE SEQUENCE xml_relation_id_seq;
214
CREATE TABLE xml_relation (
215
	relationid    INT8 default nextval('xml_relation_id_seq') PRIMARY KEY,
216
					     -- unique id
217
	docid         VARCHAR(250) ,         -- the docid of the package file
218
	                                     -- that this relation came from
219
        packagetype   VARCHAR(250),          -- the type of the package
220
	subject       VARCHAR(512) NOT NULL, -- the subject of the relation
221
	subdoctype    VARCHAR(128),         	-- the doctype of the subject
222
	relationship  VARCHAR(128)  NOT NULL,-- the relationship type
223
	object        VARCHAR(512) NOT NULL, -- the object of the relation
224
	objdoctype    VARCHAR(128),          -- the doctype of the object
225
	CONSTRAINT xml_relation_uk UNIQUE (subject, relationship, object),
226
	CONSTRAINT xml_relation_docid_fk 
227
		FOREIGN KEY (docid) REFERENCES xml_documents
228
  );
229

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

    
240

    
241

    
(13-13/13)