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: 08 May 2001 
7
 *       Author: John Harris
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
 *
12
 *	this is sql script does the same as the sql script named 
13
 *	xmltables.sql except that this script is to be use to 
14
 *	create the database tables on a Postgresql backend rather
15
 *	than an Oracle Backend
16
 */
17

    
18
/*
19
 * Drop all of the objects in proper order
20
 */
21
set echo off
22

    
23
DROP SEQUENCE xml_nodes_id_seq;
24
DROP SEQUENCE xml_revisions_id_seq;
25
DROP SEQUENCE xml_catalog_id_seq;
26
DROP SEQUENCE xml_relation_id_seq;
27
DROP SEQUENCE xml_replication_id_seq;
28
DROP SEQUENCE accnum_uniqueid_seq;
29
DROP SEQUENCE xml_documents_id_seq;
30

    
31
DROP TABLE xml_index;
32
DROP TABLE xml_access;
33
DROP TABLE xml_revisions;
34
DROP TABLE xml_relation;
35
DROP TABLE xml_documents;
36
DROP TABLE xml_nodes;
37
DROP TABLE xml_replication;
38
DROP TABLE xml_catalog;
39

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

    
52
INSERT INTO xml_replication (serverid, server, replicate) VALUES ('1', 'localhost', '0');
53

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

    
77
/* 
78
 * Indexes of rootnodeid & parentnodeid in xml_nodes
79
 */
80
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
81
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
82
CREATE SEQUENCE xml_nodes_id_seq;
83

    
84

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

    
101

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

    
131
/* 
132
 * Index of <docid,doctype> in xml_document
133
 */
134
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
135

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

    
164

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

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

    
200
/* 
201
 * Index of the paths in xml_index 
202
 */
203
CREATE INDEX xml_index_idx1 ON xml_index (path);
204

    
205

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

    
222

    
(13-13/13)