Project

General

Profile

1
/**
2
 *  '$RCSfile$'
3
 *  Copyright: 2004 Regents of the University of California and the
4
 *             National Center for Ecological Analysis and Synthesis
5
 *
6
 *   '$Author: jones $'
7
 *     '$Date: 2005-09-27 16:48:07 -0700 (Tue, 27 Sep 2005) $'
8
 * '$Revision: 2599 $'
9
 *
10
 * This program is free software, you can redistribute it and/or modify
11
 * it under the terms of the GNU General Public License as published by
12
 * the Free Software Foundation, either version 2 of the License, or
13
 * (at your option) any later version.
14
 *
15
 * This program is distributed in the hope that it will be useful,
16
 * but WITHOUT ANY WARRANTY, without even the implied warranty of
17
 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
18
 * GNU General Public License for more details.
19
 *
20
 * You should have received a copy of the GNU General Public License
21
 * along with this program, if not, write to the Free Software
22
 * Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA  02111-1307  USA
23
 */
24

    
25
/*
26
 * this is sql script does the same as the sql script named
27
 * xmltables.sql except that this script is to be use to
28
 * create the database tables on a Postgresql backend rather
29
 * than an Oracle Backend
30
 */
31

    
32
/*
33
 * Replication -- table to store servers that metacat is replicated to
34
 */
35
CREATE SEQUENCE xml_replication_id_seq;
36
CREATE TABLE xml_replication (
37
  serverid INT8 default nextval('xml_replication_id_seq'),
38
  server VARCHAR(512),
39
  last_checked DATE,
40
  replicate INT8,
41
  datareplicate INT8,
42
  hub INT8,
43
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
44
);
45

    
46
INSERT INTO xml_replication (server, replicate, datareplicate, hub) VALUES ('localhost', '0', '0', '0');
47

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

    
82

    
83
/*
84
 * Table for storing the nodes for the old revisions of the document and the deleted documents
85
 */
86
CREATE TABLE xml_nodes_revisions (
87
        nodeid INT8,            -- the unique node id (pk)
88
        nodeindex INT8,         -- order of nodes within parent
89
        nodetype VARCHAR(20),   -- type (DOCUMENT, COMMENT, PI,
90
                                -- ELEMENT, ATTRIBUTE, TEXT)
91
        nodename VARCHAR(250),  -- the name of an element or attribute
92
        nodeprefix VARCHAR(50), -- the namespace prefix of the node
93
        nodedata VARCHAR(4000), -- the data for this node (e.g.,
94
                                -- for TEXT it is the content)
95
        parentnodeid INT8,      -- index of the parent of this node
96
        rootnodeid INT8,        -- index of the root node of this tree
97
        docid VARCHAR(250),     -- index to the document id
98
        date_created DATE,
99
        date_updated DATE,
100
        nodedatanumerical FLOAT8, -- the data for this node if
101
                                  -- if it is a number
102
   CONSTRAINT xml_nodes_revisions_pk PRIMARY KEY (nodeid),
103
   CONSTRAINT xml_nodes_revisions_root_fk
104
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions,
105
   CONSTRAINT xml_nodes_revisions_parent_fk
106
                FOREIGN KEY (parentnodeid) REFERENCES xml_nodes_revisions
107
);
108
                                                                                                                                                             
109
/*
110
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes_revisions
111
 */
112
CREATE INDEX xml_nodes_revisions_idx1 ON xml_nodes_revisions (rootnodeid);
113
CREATE INDEX xml_nodes_revisions_idx2 ON xml_nodes_revisions (parentnodeid);
114
CREATE INDEX xml_nodes_revisions_idx3 ON xml_nodes_revisions (nodename);
115
                                                                                                                                                             
116

    
117

    
118
/*
119
 * XML Catalog -- table to store all external sources for XML documents
120
 */
121
CREATE SEQUENCE xml_catalog_id_seq;
122
CREATE TABLE xml_catalog (
123
	catalog_id INT8 default nextval('xml_catalog_id_seq'),
124
                                        -- the id for this catalog entry
125
	entry_type VARCHAR(500),	-- the type of this catalog entry
126
					-- (e.g., DTD, XSD, XSL)
127
	source_doctype VARCHAR(500),	-- the source public_id for transforms
128
	target_doctype VARCHAR(500),	-- the target public_id for transforms
129
	public_id VARCHAR(500),	-- the unique id for this type
130
	system_id VARCHAR(1000),	-- the local location of the object
131
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
132
   CONSTRAINT xml_catalog_uk UNIQUE
133
              (entry_type, source_doctype, target_doctype, public_id)
134
);
135

    
136
/*
137
 * Sequence to get uniqueID for Accession #
138
 */
139
CREATE SEQUENCE xml_documents_id_seq;
140
/*
141
 * Documents -- table to store XML documents
142
 */
143
CREATE TABLE xml_documents (
144
	docid VARCHAR(250),	-- the document id #
145
	rootnodeid INT8,		-- reference to root node of the DOM
146
	docname VARCHAR(100),	-- usually the root element name
147
	doctype VARCHAR(100),	-- public id indicating document type
148
	user_owner VARCHAR(100),	-- the user owned the document
149
	user_updated VARCHAR(100),	-- the user updated the document
150
	server_location INT8,	-- the server on which this document resides
151
	rev INT8 default 1,   -- the revision number of the document
152
	date_created DATE,
153
	date_updated DATE,
154
	public_access INT8,	-- flag for public access
155
        catalog_id INT8,	-- reference to xml_catalog
156
     CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
157
     CONSTRAINT xml_documents_rep_fk
158
     		FOREIGN KEY (server_location) REFERENCES xml_replication,
159
    CONSTRAINT xml_documents_root_fk
160
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
161
   CONSTRAINT xml_documents_catalog_fk
162
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
163
);
164

    
165
/*
166
 * Index of <docid,doctype> in xml_document
167
 */
168
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
169

    
170
/*
171
 * Revised Documents -- table to store XML documents saved after an UPDATE
172
 *                    or DELETE
173
 */
174
CREATE SEQUENCE xml_revisions_id_seq;
175
CREATE TABLE xml_revisions (
176
	revisionid INT8  default nextval('xml_revisions_id_seq'),
177
                                        -- the revision number we are saving
178
	docid VARCHAR(250),	-- the document id #
179
	rootnodeid INT8,		-- reference to root node of the DOM
180
	docname VARCHAR(100),	-- usually the root element name
181
	doctype VARCHAR(100),	-- public id indicating document type
182
	user_owner VARCHAR(100),
183
	user_updated VARCHAR(100),
184
	server_location INT8,
185
	rev INT8,
186
	date_created DATE,
187
	date_updated DATE,
188
	public_access INT8,	-- flag for public access
189
        catalog_id INT8,	-- reference to xml_catalog
190
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
191
   CONSTRAINT xml_revisions_rep_fk
192
		FOREIGN KEY (server_location) REFERENCES xml_replication,
193
   CONSTRAINT xml_revisions_root_fk
194
		FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions,
195
   CONSTRAINT xml_revisions_catalog_fk
196
		FOREIGN KEY (catalog_id) REFERENCES xml_catalog
197
);
198

    
199

    
200
/*
201
 * ACL -- table to store ACL for XML documents by principals
202
 */
203
CREATE TABLE xml_access (
204
	docid VARCHAR(250),	-- the document id #
205
	accessfileid VARCHAR(250),	-- the document id # for the access file
206
	principal_name VARCHAR(100),	-- name of user, group, etc.
207
	permission INT8,		-- "read", "write", "all"
208
	perm_type VARCHAR(32),	-- "allowed" or "denied"
209
	perm_order VARCHAR(32),	-- "allow first" or "deny first"
210
	begin_time DATE,		-- the time that permission begins
211
	end_time DATE,		-- the time that permission ends
212
	ticket_count INT8,		-- ticket counter for that permission
213
  subtreeid VARCHAR(32),
214
  startnodeid INT8,
215
  endnodeid INT8,
216
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
217
   CONSTRAINT xml_access_accessfileid_fk
218
		FOREIGN KEY (accessfileid) REFERENCES xml_documents
219
);
220

    
221
/*
222
 * Index of Nodes -- table to store precomputed paths through tree for
223
 * quick searching in structured searches
224
 */
225
CREATE TABLE xml_index (
226
	nodeid INT8,		-- the unique node id
227
	path VARCHAR(1000),	-- precomputed path through tree
228
	docid VARCHAR(250),	-- index to the document id
229
	doctype VARCHAR(100),	-- public id indicating document type
230
        parentnodeid INT8,      -- id of the parent of the node represented
231
				-- by this row
232
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
233
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
234
   CONSTRAINT xml_index_docid_fk
235
		FOREIGN KEY (docid) REFERENCES xml_documents
236
);
237

    
238
/*
239
 * Index of the paths in xml_index
240
 */
241
CREATE INDEX xml_index_idx1 ON xml_index (path);
242

    
243
CREATE SEQUENCE xml_relation_id_seq;
244
CREATE TABLE xml_relation (
245
	relationid INT8 default nextval('xml_relation_id_seq') PRIMARY KEY,
246
					     -- unique id
247
	docid VARCHAR(250) ,         -- the docid of the package file
248
	                                     -- that this relation came from
249
        packagetype VARCHAR(250),          -- the type of the package
250
	subject VARCHAR(512) NOT NULL, -- the subject of the relation
251
	subdoctype VARCHAR(128),         	-- the doctype of the subject
252
	relationship VARCHAR(128)  NOT NULL,-- the relationship type
253
	object VARCHAR(512) NOT NULL, -- the object of the relation
254
	objdoctype VARCHAR(128),          -- the doctype of the object
255
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
256
	CONSTRAINT xml_relation_docid_fk
257
		FOREIGN KEY (docid) REFERENCES xml_documents
258
);
259

    
260
/*
261
 * Table used as Unique ID generator for the uniqueid part of Accession#
262
 */
263
CREATE SEQUENCE accession_number_id_seq;
264
CREATE TABLE accession_number (
265
   uniqueid INT8 default nextval('accession_number_id_seq') PRIMARY KEY,
266
   site_code VARCHAR(100),
267
   date_created DATE
268
);
269

    
270
/*
271
 * accesssubtree -- table to store access subtree info
272
 */
273
CREATE TABLE xml_accesssubtree (
274
	docid		VARCHAR(250),	-- the document id #
275
  rev 		INT8 default 1, --the revision number of the docume
276
  controllevel VARCHAR(50), -- the level it control -- document or subtree
277
  subtreeid VARCHAR(250), -- the subtree id
278
	startnodeid	INT8,	-- the start node id of access subtree
279
  endnodeid INT8, -- the end node if of access subtree
280
  CONSTRAINT xml_accesssubtree_docid_fk
281
		FOREIGN KEY (docid) REFERENCES xml_documents
282
);
283

    
284
/*
285
 * Returnfields -- table to store combinations of returnfields requested
286
 *		    and the number of times this table is accessed
287
 */
288
CREATE TABLE xml_returnfield (
289
        returnfield_id     INT8 default nextval('xml_returnfield_id_seq'),   -- the id for this returnfield entry
290
        returnfield_string VARCHAR(2000),                                    -- the returnfield string
291
        usage_count        INT8,                                             -- the number of times this string has been requested
292
        CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id)
293
);
294
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string);
295

    
296
CREATE SEQUENCE xml_returnfield_id_seq;
297

    
298
/*
299
 * Queryresults -- table to store queryresults for a given docid
300
 * and returnfield_id
301
 */
302
CREATE TABLE xml_queryresult(
303
  queryresult_id INT8 default nextval('xml_queryresult_id_seq'), -- id for this entry
304
  returnfield_id       INT8,          -- id for the returnfield corresponding to this entry
305
  docid                VARCHAR(250),  -- docid of the document
306
  queryresult_string   VARCHAR(4000), -- resultant text generated for this docid and given
307
  				       -- returnfield
308
  CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id),
309
  CONSTRAINT xml_queryresult_searchid_fk
310
               FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield
311
);
312

    
313
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid);
314

    
315
CREATE SEQUENCE xml_queryresult_id_seq;
316

    
317
/*
318
 * Logging -- table to store metadata and data access log
319
 */
320
CREATE SEQUENCE access_log_id_seq;
321
CREATE TABLE access_log (
322
  entryid       INT8 default nextval ('access_log_id_seq'), -- the identifier for the log event
323
  ip_address    VARCHAR(512),   -- the ip address inititiating the event
324
  principal     VARCHAR(512),   -- the user initiiating the event
325
  docid         VARCHAR(250),	-- the document id #
326
  event         VARCHAR(512),   -- the code symbolizing the event type
327
  date_logged   TIMESTAMP,      -- the datetime on which the event occurred
328
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
329
);
330

    
331

    
332
/*
333
 * Table for indexing the paths specified the administrator in metacat.properties
334
 */
335

    
336
CREATE SEQUENCE xml_path_index_id_seq;
337
CREATE TABLE xml_path_index (
338
    nodeid INT8  default nextval('xml_path_index_id_seq'),
339
        docid VARCHAR(250),     -- the document id
340
        path VARCHAR(1000),     -- precomputed path through tree
341
        nodedata VARCHAR(4000), -- the data for this node (e.g.,
342
                                -- for TEXT it is the content)
343
        nodedatanumerical FLOAT8, -- the data for this node if
344
                                  -- if it is a number
345
        parentnodeid INT8,      -- id of the parent of the node represented
346
                                -- by this row
347
   CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid),
348
   CONSTRAINT xml_path_index_docid_fk
349
                FOREIGN KEY (docid) REFERENCES xml_documents
350
);
351

    
352
/*
353
 * Indexes of path, nodedata and nodedatanumerical in xml_path_index
354
 */
355
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path);
356
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata);
357
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical);
358

    
359
/*
360
 * harvest_site_schedule -- table to store harvest sites and schedule info
361
 */
362
CREATE TABLE harvest_site_schedule (
363
  site_schedule_id INT8,         -- unique id
364
  documentlisturl  VARCHAR(255), -- URL of the site harvest document list
365
  ldapdn           VARCHAR(255), -- LDAP distinguished name for site account
366
  datenextharvest  DATE,         -- scheduled date of next harvest
367
  datelastharvest  DATE,         -- recorded date of last harvest
368
  updatefrequency  INT8,         -- the harvest update frequency
369
  unit             VARCHAR(50),  -- update unit -- days weeks or months
370
  contact_email    VARCHAR(50),  -- email address of the site contact person
371
  ldappwd          VARCHAR(20),  -- LDAP password for site account
372
  CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
373
);
374

    
375
/*
376
 * harvest_log -- table to log entries for harvest operations
377
 */
378
CREATE TABLE harvest_log (
379
  harvest_log_id         INT8,          -- unique id
380
  harvest_date           DATE,          -- date of the current harvest
381
  status                 INT8,          -- non-zero indicates an error status
382
  message                VARCHAR(1000), -- text message for this log entry
383
  harvest_operation_code VARCHAR(30),   -- the type of harvest operation
384
  site_schedule_id       INT8,          -- site schedule id, or 0 if no site
385
  CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
386
);
387

    
388
/*
389
 * harvest_detail_log -- table to log detailed info about documents that
390
 *                       generated errors during the harvest
391
 */
392
CREATE TABLE harvest_detail_log (
393
  detail_log_id          INT8,          -- unique id
394
  harvest_log_id         INT8,          -- ponter to the related log entry
395
  scope                  VARCHAR(50),   -- document scope
396
  identifier             INT8,          -- document identifier
397
  revision               INT8,          -- document revision
398
  document_url           VARCHAR(255),  -- document URL
399
  error_message          VARCHAR(1000), -- text error message
400
  document_type          VARCHAR(100),  -- document type
401
  CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
402
  CONSTRAINT harvest_detail_log_fk
403
        FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
404
);
405

    
406

    
(27-27/29)