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: tao $'
7
 *     '$Date: 2007-09-10 18:22:06 -0700 (Mon, 10 Sep 2007) $'
8
 * '$Revision: 3412 $'
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 TEXT, -- 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
CREATE INDEX xml_nodes_idx4 ON xml_nodes (docid);
82

    
83

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

    
118

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

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

    
166
/*
167
 * Index of <docid,doctype> in xml_document
168
 */
169
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
170
CREATE INDEX xml_documents_idx2 ON xml_documents (lower(user_owner));
171

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

    
201

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

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

    
245
/*
246
 * Index of the paths in xml_index
247
 */
248
CREATE INDEX xml_index_idx1 ON xml_index (path);
249
CREATE INDEX xml_index_idx2 ON xml_index (docid);
250

    
251
CREATE SEQUENCE xml_relation_id_seq;
252
CREATE TABLE xml_relation (
253
	relationid INT8 default nextval('xml_relation_id_seq') PRIMARY KEY,
254
					     -- unique id
255
	docid VARCHAR(250) ,         -- the docid of the package file
256
	                                     -- that this relation came from
257
        packagetype VARCHAR(250),          -- the type of the package
258
	subject VARCHAR(512) NOT NULL, -- the subject of the relation
259
	subdoctype VARCHAR(128),         	-- the doctype of the subject
260
	relationship VARCHAR(128)  NOT NULL,-- the relationship type
261
	object VARCHAR(512) NOT NULL, -- the object of the relation
262
	objdoctype VARCHAR(128),          -- the doctype of the object
263
	CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
264
	CONSTRAINT xml_relation_docid_fk
265
		FOREIGN KEY (docid) REFERENCES xml_documents
266
);
267

    
268
/*
269
 * Table used to store all document identifiers in metacat.  Each identifier
270
 * consists of 4 subparts, an authority, namespace, object, and revision as
271
 * defined in the LSID specification.
272
 */
273
CREATE SEQUENCE identifier_id_seq;
274
CREATE TABLE identifier (
275
   id INT8 default nextval('identifier_id_seq') PRIMARY KEY, -- primary id
276
   authority VARCHAR(255),  -- the authority issuing the identifier
277
   namespace VARCHAR(255),  -- the namespace qualifying the identifier
278
   object    VARCHAR(255),  -- the local part of the identifier for a particular object
279
   revision  VARCHAR(255)   -- the revision part of the identifier
280
);
281

    
282
/*
283
 * accesssubtree -- table to store access subtree info
284
 */
285
CREATE TABLE xml_accesssubtree (
286
	docid		VARCHAR(250),	-- the document id #
287
  rev 		INT8 default 1, --the revision number of the docume
288
  controllevel VARCHAR(50), -- the level it control -- document or subtree
289
  subtreeid VARCHAR(250), -- the subtree id
290
	startnodeid	INT8,	-- the start node id of access subtree
291
  endnodeid INT8, -- the end node if of access subtree
292
  CONSTRAINT xml_accesssubtree_docid_fk
293
		FOREIGN KEY (docid) REFERENCES xml_documents
294
);
295

    
296
/*
297
 * Returnfields -- table to store combinations of returnfields requested
298
 *		    and the number of times this table is accessed
299
 */
300
CREATE SEQUENCE xml_returnfield_id_seq;
301
CREATE TABLE xml_returnfield (
302
        returnfield_id     INT8 default nextval('xml_returnfield_id_seq'),   -- the id for this returnfield entry
303
        returnfield_string VARCHAR(2000),                                    -- the returnfield string
304
        usage_count        INT8,                                             -- the number of times this string has been requested
305
        CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id)
306
);
307
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string);
308

    
309
/*
310
 * Queryresults -- table to store queryresults for a given docid
311
 * and returnfield_id
312
 */
313
CREATE SEQUENCE xml_queryresult_id_seq;
314
CREATE TABLE xml_queryresult(
315
  queryresult_id INT8 default nextval('xml_queryresult_id_seq'), -- id for this entry
316
  returnfield_id       INT8,          -- id for the returnfield corresponding to this entry
317
  docid                VARCHAR(250),  -- docid of the document
318
  queryresult_string   TEXT, -- resultant text generated for this docid and given
319
  				       -- returnfield
320
  CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id),
321
  CONSTRAINT xml_queryresult_searchid_fk
322
               FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield
323
);
324

    
325
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid);
326

    
327
/*
328
 * Logging -- table to store metadata and data access log
329
 */
330
CREATE SEQUENCE access_log_id_seq;
331
CREATE TABLE access_log (
332
  entryid       INT8 default nextval ('access_log_id_seq'), -- the identifier for the log event
333
  ip_address    VARCHAR(512),   -- the ip address inititiating the event
334
  principal     VARCHAR(512),   -- the user initiiating the event
335
  docid         VARCHAR(250),	-- the document id #
336
  event         VARCHAR(512),   -- the code symbolizing the event type
337
  date_logged   TIMESTAMP,      -- the datetime on which the event occurred
338
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
339
);
340

    
341

    
342
/*
343
 * Table for indexing the paths specified the administrator in metacat.properties
344
 */
345

    
346
CREATE SEQUENCE xml_path_index_id_seq;
347
CREATE TABLE xml_path_index (
348
    nodeid INT8  default nextval('xml_path_index_id_seq'),
349
        docid VARCHAR(250),     -- the document id
350
        path VARCHAR(1000),     -- precomputed path through tree
351
        nodedata TEXT, -- the data for this node (e.g.,
352
                                -- for TEXT it is the content)
353
        nodedatanumerical FLOAT8, -- the data for this node if
354
                                  -- if it is a number
355
        parentnodeid INT8,      -- id of the parent of the node represented
356
                                -- by this row
357
   CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid),
358
   CONSTRAINT xml_path_index_docid_fk
359
                FOREIGN KEY (docid) REFERENCES xml_documents
360
);
361

    
362
/*
363
 * Indexes of path, nodedata and nodedatanumerical in xml_path_index
364
 */
365
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path);
366
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata);
367
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical);
368
CREATE INDEX xml_path_index_idx4 ON xml_path_index (upper(nodedata));
369

    
370
/*
371
 * harvest_site_schedule -- table to store harvest sites and schedule info
372
 */
373
CREATE TABLE harvest_site_schedule (
374
  site_schedule_id INT8,         -- unique id
375
  documentlisturl  VARCHAR(255), -- URL of the site harvest document list
376
  ldapdn           VARCHAR(255), -- LDAP distinguished name for site account
377
  datenextharvest  DATE,         -- scheduled date of next harvest
378
  datelastharvest  DATE,         -- recorded date of last harvest
379
  updatefrequency  INT8,         -- the harvest update frequency
380
  unit             VARCHAR(50),  -- update unit -- days weeks or months
381
  contact_email    VARCHAR(50),  -- email address of the site contact person
382
  ldappwd          VARCHAR(20),  -- LDAP password for site account
383
  CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
384
);
385

    
386
/*
387
 * harvest_log -- table to log entries for harvest operations
388
 */
389
CREATE TABLE harvest_log (
390
  harvest_log_id         INT8,          -- unique id
391
  harvest_date           DATE,          -- date of the current harvest
392
  status                 INT8,          -- non-zero indicates an error status
393
  message                VARCHAR(1000), -- text message for this log entry
394
  harvest_operation_code VARCHAR(30),   -- the type of harvest operation
395
  site_schedule_id       INT8,          -- site schedule id, or 0 if no site
396
  CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
397
);
398

    
399
/*
400
 * harvest_detail_log -- table to log detailed info about documents that
401
 *                       generated errors during the harvest
402
 */
403
CREATE TABLE harvest_detail_log (
404
  detail_log_id          INT8,          -- unique id
405
  harvest_log_id         INT8,          -- ponter to the related log entry
406
  scope                  VARCHAR(50),   -- document scope
407
  identifier             INT8,          -- document identifier
408
  revision               INT8,          -- document revision
409
  document_url           VARCHAR(255),  -- document URL
410
  error_message          VARCHAR(1000), -- text error message
411
  document_type          VARCHAR(100),  -- document type
412
  CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
413
  CONSTRAINT harvest_detail_log_fk
414
        FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
415
);
416

    
417

    
(34-34/36)