Project

General

Profile

metacat / src / xmltables_postgres.sql @ 2099

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: 2004-04-02 10:15:04 -0800 (Fri, 02 Apr 2004) $'
8
 * '$Revision: 2099 $'
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
 * Drop all of the objects in proper order
34
 */
35

    
36
DROP SEQUENCE xml_nodes_id_seq;
37
DROP SEQUENCE xml_revisions_id_seq;
38
DROP SEQUENCE xml_catalog_id_seq;
39
DROP SEQUENCE xml_relation_id_seq;
40
DROP SEQUENCE xml_replication_id_seq;
41
DROP SEQUENCE xml_documents_id_seq;
42
DROP SEQUENCE accession_number_id_seq;
43
DROP SEQUENCE access_log_id_seq;
44

    
45
DROP TABLE xml_index;
46
DROP TABLE xml_access;
47
DROP TABLE xml_accesssubtree;
48
DROP TABLE xml_revisions;
49
DROP TABLE xml_relation;
50
DROP TABLE xml_documents;
51
DROP TABLE xml_nodes;
52
DROP TABLE xml_replication;
53
DROP TABLE xml_catalog;
54
DROP TABLE accession_number;
55
DROP TABLE access_log;
56

    
57
/*
58
 *Replication -- table to store servers that metacat is replicated to
59
 */
60
CREATE SEQUENCE xml_replication_id_seq;
61
CREATE TABLE xml_replication (
62
  serverid INT8 default nextval('xml_replication_id_seq'), 
63
  server VARCHAR(512),
64
  last_checked DATE,
65
  replicate INT8,
66
  datareplicate INT8,
67
  hub INT8,
68
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
69
);  
70

    
71
INSERT INTO xml_replication (server, replicate, datareplicate, hub) VALUES ('localhost', '0', '0', '0');
72

    
73
/* 
74
 * Nodes -- table to store XML Nodes (both elements and attributes)
75
 */
76
CREATE SEQUENCE xml_nodes_id_seq;
77
CREATE TABLE xml_nodes (
78
        nodeid INT8 default nextval('xml_nodes_id_seq'),
79
                                        -- the unique node id (pk)
80
        nodeindex INT8,                -- order of nodes within parent
81
        nodetype VARCHAR(20),        -- type (DOCUMENT, COMMENT, PI,
82
                                        -- ELEMENT, ATTRIBUTE, TEXT)
83
        nodename VARCHAR(250),        -- the name of an element or attribute
84
        nodeprefix VARCHAR(50), -- the namespace prefix of the node
85
        nodedata VARCHAR(4000),         -- the data for this node (e.g., 
86
                                        -- for TEXT it is the content)
87
        parentnodeid INT8,                -- index of the parent of this node
88
        rootnodeid INT8,                -- index of the root node of this tree
89
        docid VARCHAR(250),        -- index to the document id
90
        date_created DATE,
91
        date_updated DATE,
92
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
93
   CONSTRAINT xml_nodes_root_fk 
94
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
95
   CONSTRAINT xml_nodes_parent_fk 
96
                FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
97
);
98
/* 
99
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
100
 */
101
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
102
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
103
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
104

    
105
/* 
106
 * XML Catalog -- table to store all external sources for XML documents
107
 */
108
CREATE SEQUENCE xml_catalog_id_seq;
109
CREATE TABLE xml_catalog (
110
        catalog_id INT8 default nextval('xml_catalog_id_seq'),
111
                                        -- the id for this catalog entry
112
        entry_type VARCHAR(500),        -- the type of this catalog entry
113
                                        -- (e.g., DTD, XSD, XSL)
114
        source_doctype VARCHAR(500),        -- the source public_id for transforms
115
        target_doctype VARCHAR(500),        -- the target public_id for transforms
116
        public_id VARCHAR(500),        -- the unique id for this type
117
        system_id VARCHAR(1000),        -- the local location of the object
118
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
119
   CONSTRAINT xml_catalog_uk UNIQUE  
120
              (entry_type, source_doctype, target_doctype, public_id)
121
);
122

    
123
/* 
124
 * Sequence to get uniqueID for Accession #
125
 */
126
CREATE SEQUENCE xml_documents_id_seq;
127
/* 
128
 * Documents -- table to store XML documents
129
 */
130
CREATE TABLE xml_documents (
131
        docid VARCHAR(250),        -- the document id #
132
        rootnodeid INT8,                -- reference to root node of the DOM
133
        docname VARCHAR(100),        -- usually the root element name
134
        doctype VARCHAR(100),        -- public id indicating document type
135
        user_owner VARCHAR(100),        -- the user owned the document
136
        user_updated VARCHAR(100),        -- the user updated the document
137
        server_location INT8,        -- the server on which this document resides
138
        rev INT8 default 1,   -- the revision number of the document
139
        date_created DATE,
140
        date_updated DATE,
141
        public_access INT8,        -- flag for public access
142
        catalog_id INT8,        -- reference to xml_catalog 
143
     CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
144
     CONSTRAINT xml_documents_rep_fk
145
                     FOREIGN KEY (server_location) REFERENCES xml_replication, 
146
    CONSTRAINT xml_documents_root_fk 
147
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
148
   CONSTRAINT xml_documents_catalog_fk 
149
                FOREIGN KEY (catalog_id) REFERENCES xml_catalog
150
);
151

    
152
/* 
153
 * Index of <docid,doctype> in xml_document
154
 */
155
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
156

    
157
/* 
158
 * Revised Documents -- table to store XML documents saved after an UPDATE
159
 *                    or DELETE
160
 */
161
CREATE SEQUENCE xml_revisions_id_seq;
162
CREATE TABLE xml_revisions (
163
        revisionid INT8  default nextval('xml_revisions_id_seq'),
164
                                        -- the revision number we are saving
165
        docid VARCHAR(250),        -- the document id #
166
        rootnodeid INT8,                -- reference to root node of the DOM
167
        docname VARCHAR(100),        -- usually the root element name
168
        doctype VARCHAR(100),        -- public id indicating document type
169
        user_owner VARCHAR(100),
170
        user_updated VARCHAR(100),
171
        server_location INT8,
172
        rev INT8,
173
        date_created DATE,
174
        date_updated DATE,
175
        public_access INT8,        -- flag for public access
176
        catalog_id INT8,        -- reference to xml_catalog 
177
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
178
   CONSTRAINT xml_revisions_rep_fk
179
                FOREIGN KEY (server_location) REFERENCES xml_replication,
180
   CONSTRAINT xml_revisions_root_fk 
181
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
182
   CONSTRAINT xml_revisions_catalog_fk 
183
                FOREIGN KEY (catalog_id) REFERENCES xml_catalog
184
);
185

    
186

    
187
/* 
188
 * ACL -- table to store ACL for XML documents by principals
189
 */
190
CREATE TABLE xml_access (
191
        docid VARCHAR(250),        -- the document id #
192
        accessfileid VARCHAR(250),        -- the document id # for the access file
193
        principal_name VARCHAR(100),        -- name of user, group, etc.
194
        permission INT8,                -- "read", "write", "all"
195
        perm_type VARCHAR(32),        -- "allowed" or "denied"
196
        perm_order VARCHAR(32),        -- "allow first" or "deny first"
197
        begin_time DATE,                -- the time that permission begins
198
        end_time DATE,                -- the time that permission ends
199
        ticket_count INT8,                -- ticket counter for that permission
200
  subtreeid VARCHAR(32),
201
  startnodeid INT8,
202
  endnodeid INT8,
203
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
204
   CONSTRAINT xml_access_accessfileid_fk 
205
                FOREIGN KEY (accessfileid) REFERENCES xml_documents
206
);
207

    
208
/* 
209
 * Index of Nodes -- table to store precomputed paths through tree for 
210
 * quick searching in structured searches
211
 */
212
CREATE TABLE xml_index (
213
        nodeid INT8,                -- the unique node id
214
        path VARCHAR(200),        -- precomputed path through tree
215
        docid VARCHAR(250),        -- index to the document id
216
        doctype VARCHAR(100),        -- public id indicating document type
217
        parentnodeid INT8,     -- id of the parent of the node represented
218
                                        -- by this row
219
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
220
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
221
   CONSTRAINT xml_index_docid_fk 
222
                FOREIGN KEY (docid) REFERENCES xml_documents
223
);
224

    
225
/* 
226
 * Index of the paths in xml_index 
227
 */
228
CREATE INDEX xml_index_idx1 ON xml_index (path);
229

    
230

    
231
CREATE SEQUENCE xml_relation_id_seq;
232
CREATE TABLE xml_relation (
233
        relationid INT8 default nextval('xml_relation_id_seq') PRIMARY KEY,
234
                                             -- unique id
235
        docid VARCHAR(250) ,         -- the docid of the package file
236
                                             -- that this relation came from
237
        packagetype VARCHAR(250),          -- the type of the package
238
        subject VARCHAR(512) NOT NULL, -- the subject of the relation
239
        subdoctype VARCHAR(128),                 -- the doctype of the subject
240
        relationship VARCHAR(128)  NOT NULL,-- the relationship type
241
        object VARCHAR(512) NOT NULL, -- the object of the relation
242
        objdoctype VARCHAR(128),          -- the doctype of the object
243
        CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
244
        CONSTRAINT xml_relation_docid_fk 
245
                FOREIGN KEY (docid) REFERENCES xml_documents
246
);
247

    
248
/* 
249
 * Table used as Unique ID generator for the uniqueid part of Accession#
250
 */
251
CREATE SEQUENCE accession_number_id_seq;
252
CREATE TABLE accession_number (
253
   uniqueid INT8 default nextval('accession_number_id_seq') PRIMARY KEY,
254
   site_code VARCHAR(100),
255
   date_created DATE
256
);
257

    
258
/* 
259
 * accesssubtree -- table to store access subtree info 
260
 */
261
CREATE TABLE xml_accesssubtree (
262
        docid                VARCHAR(250),        -- the document id #
263
  rev                 INT8 default 1, --the revision number of the docume
264
  controllevel VARCHAR(50), -- the level it control -- document or subtree
265
  subtreeid VARCHAR(250), -- the subtree id 
266
        startnodeid        INT8,        -- the start node id of access subtree
267
  endnodeid INT8, -- the end node if of access subtree
268
  CONSTRAINT xml_accesssubtree_docid_fk 
269
                FOREIGN KEY (docid) REFERENCES xml_documents
270
);
271

    
272
/*
273
 * Logging -- table to store metadata and data access log
274
 */
275
CREATE SEQUENCE access_log_id_seq;
276
CREATE TABLE access_log (
277
  entryid       INT8 default nextval ('access_log_id_seq'), -- the identifier for the log event
278
  ip_address    VARCHAR(512),   -- the ip address inititiating the event
279
  principal     VARCHAR(512),   -- the user initiiating the event
280
  docid         VARCHAR(250),        -- the document id #
281
  rev           INT8,           -- the revision number
282
  event         VARCHAR(512),   -- the code symbolizing the event type
283
  date_logged   TIMESTAMP,      -- the datetime on which the event occurred
284
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
285
);