Project

General

Profile

metacat / src / xmltables-postgres.sql @ 2442

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: sgarg $'
7
 *     '$Date: 2005-04-04 10:12:31 -0700 (Mon, 04 Apr 2005) $'
8
 * '$Revision: 2442 $'
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
 * XML Catalog -- table to store all external sources for XML documents
84
 */
85
CREATE SEQUENCE xml_catalog_id_seq;
86
CREATE TABLE xml_catalog (
87
        catalog_id INT8 default nextval('xml_catalog_id_seq'),
88
                                        -- the id for this catalog entry
89
        entry_type VARCHAR(500),        -- the type of this catalog entry
90
                                        -- (e.g., DTD, XSD, XSL)
91
        source_doctype VARCHAR(500),        -- the source public_id for transforms
92
        target_doctype VARCHAR(500),        -- the target public_id for transforms
93
        public_id VARCHAR(500),        -- the unique id for this type
94
        system_id VARCHAR(1000),        -- the local location of the object
95
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
96
   CONSTRAINT xml_catalog_uk UNIQUE
97
              (entry_type, source_doctype, target_doctype, public_id)
98
);
99

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

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

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

    
163

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

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

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

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

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

    
234
/*
235
 * accesssubtree -- table to store access subtree info
236
 */
237
CREATE TABLE xml_accesssubtree (
238
        docid                VARCHAR(250),        -- the document id #
239
  rev                 INT8 default 1, --the revision number of the docume
240
  controllevel VARCHAR(50), -- the level it control -- document or subtree
241
  subtreeid VARCHAR(250), -- the subtree id
242
        startnodeid        INT8,        -- the start node id of access subtree
243
  endnodeid INT8, -- the end node if of access subtree
244
  CONSTRAINT xml_accesssubtree_docid_fk
245
                FOREIGN KEY (docid) REFERENCES xml_documents
246
);
247

    
248
/*
249
 * Returnfields -- table to store combinations of returnfields requested
250
 *                    and the number of times this table is accessed
251
 */
252
CREATE TABLE xml_returnfield (
253
        returnfield_id     INT8 default nextval('xml_returnfield_id_seq'),   -- the id for this returnfield entry
254
        returnfield_string VARCHAR(2000),                                    -- the returnfield string
255
        usage_count        INT8,                                             -- the number of times this string has been requested
256
        CONSTRAINT xml_returnfield_pk PRIMARY KEY (returnfield_id)
257
);
258
CREATE INDEX xml_returnfield_idx1 ON xml_returnfield(returnfield_string);
259

    
260
CREATE SEQUENCE xml_returnfield_id_seq;
261

    
262
/*
263
 * Queryresults -- table to store queryresults for a given docid
264
 * and returnfield_id
265
 */
266
CREATE TABLE xml_queryresult(
267
  queryresult_id INT8 default nextval('xml_queryresult_id_seq'), -- id for this entry
268
  returnfield_id       INT8,          -- id for the returnfield corresponding to this entry
269
  docid                VARCHAR(250),  -- docid of the document
270
  queryresult_string   VARCHAR(4000), -- resultant text generated for this docid and given
271
                                         -- returnfield
272
  CONSTRAINT xml_queryresult_pk PRIMARY KEY (queryresult_id),
273
  CONSTRAINT xml_queryresult_searchid_fk
274
               FOREIGN KEY (returnfield_id) REFERENCES xml_returnfield
275
);
276

    
277
CREATE INDEX xml_queryresult_idx1 ON xml_queryresult (returnfield_id, docid);
278

    
279
CREATE SEQUENCE xml_queryresult_id_seq;
280

    
281
/*
282
 * Logging -- table to store metadata and data access log
283
 */
284
CREATE SEQUENCE access_log_id_seq;
285
CREATE TABLE access_log (
286
  entryid       INT8 default nextval ('access_log_id_seq'), -- the identifier for the log event
287
  ip_address    VARCHAR(512),   -- the ip address inititiating the event
288
  principal     VARCHAR(512),   -- the user initiiating the event
289
  docid         VARCHAR(250),        -- the document id #
290
  event         VARCHAR(512),   -- the code symbolizing the event type
291
  date_logged   TIMESTAMP,      -- the datetime on which the event occurred
292
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
293
);
294

    
295
/*
296
 * harvest_site_schedule -- table to store harvest sites and schedule info
297
 */
298
CREATE TABLE harvest_site_schedule (
299
  site_schedule_id INT8,         -- unique id
300
  documentlisturl  VARCHAR(255), -- URL of the site harvest document list
301
  ldapdn           VARCHAR(255), -- LDAP distinguished name for site account
302
  datenextharvest  DATE,         -- scheduled date of next harvest
303
  datelastharvest  DATE,         -- recorded date of last harvest
304
  updatefrequency  INT8,         -- the harvest update frequency
305
  unit             VARCHAR(50),  -- update unit -- days weeks or months
306
  contact_email    VARCHAR(50),  -- email address of the site contact person
307
  ldappwd          VARCHAR(20),  -- LDAP password for site account
308
  CONSTRAINT harvest_site_schedule_pk PRIMARY KEY (site_schedule_id)
309
);
310

    
311
/*
312
 * harvest_log -- table to log entries for harvest operations
313
 */
314
CREATE TABLE harvest_log (
315
  harvest_log_id         INT8,          -- unique id
316
  harvest_date           DATE,          -- date of the current harvest
317
  status                 INT8,          -- non-zero indicates an error status
318
  message                VARCHAR(1000), -- text message for this log entry
319
  harvest_operation_code VARCHAR(30),   -- the type of harvest operation
320
  site_schedule_id       INT8,          -- site schedule id, or 0 if no site
321
  CONSTRAINT harvest_log_pk PRIMARY KEY (harvest_log_id)
322
);
323

    
324
/*
325
 * harvest_detail_log -- table to log detailed info about documents that
326
 *                       generated errors during the harvest
327
 */
328
CREATE TABLE harvest_detail_log (
329
  detail_log_id          INT8,          -- unique id
330
  harvest_log_id         INT8,          -- ponter to the related log entry
331
  scope                  VARCHAR(50),   -- document scope
332
  identifier             INT8,          -- document identifier
333
  revision               INT8,          -- document revision
334
  document_url           VARCHAR(255),  -- document URL
335
  error_message          VARCHAR(1000), -- text error message
336
  document_type          VARCHAR(100),  -- document type
337
  CONSTRAINT harvest_detail_log_pk PRIMARY KEY (detail_log_id),
338
  CONSTRAINT harvest_detail_log_fk
339
        FOREIGN KEY (harvest_log_id) REFERENCES harvest_log
340
);
341