Project

General

Profile

metacat / src / xmltables.sql @ 2108

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 11:43:13 -0800 (Fri, 02 Apr 2004) $'
8
 * '$Revision: 2101 $'
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
 * Drop all of the objects in proper order
27
 */
28
set echo off
29

    
30
DROP SEQUENCE xml_nodes_id_seq;
31
DROP SEQUENCE xml_revisions_id_seq;
32
DROP SEQUENCE xml_catalog_id_seq;
33
DROP SEQUENCE xml_relation_id_seq;
34
DROP SEQUENCE xml_replication_id_seq;
35
DROP SEQUENCE accnum_uniqueid_seq;
36
DROP SEQUENCE xml_documents_id_seq;
37
DROP SEQUENCE accession_number_id_seq;
38
DROP SEQUENCE access_log_seq;
39
               
40
/* Drop triggers are not necessary */
41
DROP TRIGGER xml_nodes_before_insert;
42
DROP TRIGGER xml_revisions_before_insert;
43
DROP TRIGGER xml_catalog_before_insert;
44
DROP TRIGGER xml_relation_before_insert;
45
DROP TRIGGER xml_replication_before_insert;
46
DROP TRIGGER accession_number_before_insert;
47
DROP TRIGGER access_log_before_insert;
48

    
49
DROP TABLE xml_index;
50
DROP TABLE xml_access;
51
DROP TABLE xml_accesssubtree;
52
DROP TABLE xml_revisions;
53
DROP TABLE xml_relation;
54
DROP TABLE xml_documents;
55
DROP TABLE xml_nodes;
56
DROP TABLE xml_replication;
57
DROP TABLE xml_catalog;
58
DROP TABLE accession_number;
59
DROP TABLE access_log;
60

    
61
/*
62
 *Replication -- table to store servers that metacat is replicated to
63
 */
64
CREATE TABLE xml_replication (
65
  serverid      NUMBER(20),
66
  server        VARCHAR2(512),
67
  last_checked  DATE,
68
  replicate     NUMBER(1),
69
  datareplicate NUMBER(1),
70
  hub NUMBER(1),
71
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
72
);  
73
  
74
CREATE SEQUENCE xml_replication_id_seq;
75
CREATE TRIGGER xml_replication_before_insert
76
BEFORE INSERT ON xml_replication FOR EACH ROW
77
BEGIN
78
  SELECT xml_replication_id_seq.nextval
79
    INTO :new.serverid
80
    FROM dual;
81
END;
82
/
83

    
84
INSERT INTO xml_replication (server, replicate, datareplicate, hub)
85
 VALUES ('localhost', '0', '0', '0');
86

    
87
/* 
88
 * Nodes -- table to store XML Nodes (both elements and attributes)
89
 */
90
CREATE SEQUENCE xml_nodes_id_seq;
91
CREATE TABLE xml_nodes (
92
        nodeid                NUMBER(20),        -- the unique node id (pk)
93
        nodeindex        NUMBER(10),        -- order of nodes within parent
94
        nodetype        VARCHAR2(20),        -- type (DOCUMENT, COMMENT, PI,
95
                                        -- ELEMENT, ATTRIBUTE, TEXT)
96
        nodename        VARCHAR2(250),        -- the name of an element or attribute
97
        nodeprefix        VARCHAR2(50),        -- the namespace prefix of an element
98
                                        -- or attribute
99
        nodedata        VARCHAR2(4000), -- the data for this node (e.g., 
100
                                        -- for TEXT it is the content)
101
        parentnodeid        NUMBER(20),        -- index of the parent of this node
102
        rootnodeid        NUMBER(20),        -- index of the root node of this tree
103
        docid                VARCHAR2(250),        -- index to the document id
104
        date_created        DATE,
105
        date_updated        DATE,
106
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
107
   CONSTRAINT xml_nodes_root_fk 
108
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
109
   CONSTRAINT xml_nodes_parent_fk 
110
                FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
111
);
112
CREATE TRIGGER xml_nodes_before_insert
113
BEFORE INSERT ON xml_nodes FOR EACH ROW
114
BEGIN
115
  SELECT xml_nodes_id_seq.nextval
116
    INTO :new.nodeid
117
    FROM dual;     
118
END;    
119
/
120
                               
121
/* 
122
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
123
 */
124
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
125
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
126
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
127

    
128
/* 
129
 * XML Catalog -- table to store all external sources for XML documents
130
 */
131
CREATE TABLE xml_catalog (
132
        catalog_id        NUMBER(20),        -- the id for this catalog entry
133
        entry_type        VARCHAR2(500),        -- the type of this catalog entry
134
                                        -- (e.g., DTD, XSD, XSL)
135
        source_doctype        VARCHAR2(500),        -- the source public_id for transforms
136
        target_doctype        VARCHAR2(500),        -- the target public_id for transforms
137
        public_id        VARCHAR2(500),        -- the unique id for this type
138
        system_id        VARCHAR2(1000),        -- the local location of the object
139
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
140
   CONSTRAINT xml_catalog_uk UNIQUE 
141
                (entry_type, source_doctype, target_doctype, public_id)
142
);
143

    
144
CREATE SEQUENCE xml_catalog_id_seq;
145

    
146
CREATE TRIGGER xml_catalog_before_insert
147
BEFORE INSERT ON xml_catalog FOR EACH ROW
148
BEGIN
149
  SELECT xml_catalog_id_seq.nextval
150
    INTO :new.catalog_id
151
    FROM dual;
152
END;
153
/
154

    
155
/* 
156
 * Documents -- table to store XML documents
157
 */
158
CREATE TABLE xml_documents (
159
        docid                VARCHAR2(250),        -- the document id #
160
        rootnodeid        NUMBER(20),        -- reference to root node of the DOM
161
        docname                VARCHAR2(100),        -- usually the root element name
162
        doctype                VARCHAR2(100),        -- public id indicating document type
163
        user_owner        VARCHAR2(100),        -- the user owned the document
164
        user_updated        VARCHAR2(100),        -- the user updated the document
165
        server_location NUMBER(20),        -- the server on which this document 
166
                                        -- originates
167
        rev                 NUMBER(10) DEFAULT 1,--the revision number of the docume
168
        date_created        DATE,
169
        date_updated        DATE,
170
        public_access        NUMBER(1),        -- flag for public access
171
        catalog_id      NUMBER(20),        -- reference to xml_catalog 
172
   CONSTRAINT xml_documents_pk PRIMARY KEY (docid),
173
   CONSTRAINT xml_documents_rep_fk
174
                    FOREIGN KEY (server_location) REFERENCES xml_replication, 
175
   CONSTRAINT xml_documents_root_fk 
176
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
177
   CONSTRAINT xml_documents_catalog_fk 
178
                FOREIGN KEY (catalog_id) REFERENCES xml_catalog
179
);
180

    
181
/* 
182
 * Index of <docid,doctype> in xml_document
183
 */
184
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
185

    
186
/* 
187
 * Revised Documents -- table to store XML documents saved after an UPDATE
188
 *                    or DELETE
189
 */
190
CREATE TABLE xml_revisions (
191
        revisionid        NUMBER(20),        -- the revision number we are saving
192
        docid                VARCHAR2(250),        -- the document id #
193
        rootnodeid        NUMBER(20),        -- reference to root node of the DOM
194
        docname                VARCHAR2(100),        -- usually the root element name
195
        doctype                VARCHAR2(100),        -- public id indicating document type
196
        user_owner        VARCHAR2(100),
197
        user_updated        VARCHAR2(100),
198
        server_location NUMBER(20),
199
        rev                NUMBER(10),
200
        date_created        DATE,
201
        date_updated        DATE,
202
        public_access        NUMBER(1),        -- flag for public access
203
        catalog_id      NUMBER(20),        -- reference to xml_catalog 
204
   CONSTRAINT xml_revisions_pk PRIMARY KEY (revisionid),
205
   CONSTRAINT xml_revisions_rep_fk
206
                FOREIGN KEY (server_location) REFERENCES xml_replication,
207
   CONSTRAINT xml_revisions_root_fk 
208
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
209
   CONSTRAINT xml_revisions_catalog_fk 
210
                FOREIGN KEY (catalog_id) REFERENCES xml_catalog
211
);
212

    
213
CREATE SEQUENCE xml_revisions_id_seq;
214

    
215
CREATE TRIGGER xml_revisions_before_insert
216
BEFORE INSERT ON xml_revisions FOR EACH ROW
217
BEGIN
218
  SELECT xml_revisions_id_seq.nextval
219
    INTO :new.revisionid
220
    FROM dual;
221
END;
222
/
223

    
224
/* 
225
 * ACL -- table to store ACL for XML documents by principals
226
 */
227
CREATE TABLE xml_access (
228
        docid                VARCHAR2(250),        -- the document id #
229
        accessfileid        VARCHAR2(250),        -- the document id # for the access file
230
        principal_name        VARCHAR2(100),        -- name of user, group, etc.
231
        permission        NUMBER(1),        -- "read", "write", "all"
232
        perm_type        VARCHAR2(32),        -- "allowed" or "denied"
233
        perm_order        VARCHAR2(32),        -- "allow first" or "deny first"
234
        begin_time        DATE,                -- the time that permission begins
235
        end_time        DATE,                -- the time that permission ends
236
        ticket_count        NUMBER(5),        -- ticket counter for that permission
237
  subtreeid VARCHAR2(32), -- sub tree id
238
  startnodeid NUMBER(20), -- start node for sub tree
239
  endnodeid NUMBER(20),    -- end node for sub tree
240
   CONSTRAINT xml_access_ck CHECK (begin_time < end_time),
241
   CONSTRAINT xml_access_accessfileid_fk 
242
                FOREIGN KEY (accessfileid) REFERENCES xml_documents
243
);
244

    
245
/* 
246
 * Index of Nodes -- table to store precomputed paths through tree for 
247
 * quick searching in structured searches
248
 */
249
CREATE TABLE xml_index (
250
        nodeid                NUMBER(20),        -- the unique node id
251
        path                VARCHAR2(200),        -- precomputed path through tree
252
        docid                VARCHAR2(250),        -- index to the document id
253
        doctype                VARCHAR2(100),        -- public id indicating document type
254
        parentnodeid    NUMBER(20),     -- id of the parent of the node 
255
                                        -- represented by this row
256
   CONSTRAINT xml_index_pk PRIMARY KEY (nodeid,path),
257
   CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes,
258
   CONSTRAINT xml_index_docid_fk 
259
                FOREIGN KEY (docid) REFERENCES xml_documents
260
);
261

    
262
/* 
263
 * Index of the paths in xml_index 
264
 */
265
CREATE INDEX xml_index_idx1 ON xml_index (path);
266

    
267
CREATE TABLE xml_relation (
268
        relationid    NUMBER(20) PRIMARY KEY, -- unique id
269
        docid         VARCHAR2(250),          -- the docid of the package file
270
                                              -- that this relation came from
271
        packagetype   VARCHAR2(250),          -- the type of the package
272
        subject       VARCHAR2(512) NOT NULL, -- the subject of the relation
273
        subdoctype    VARCHAR2(128),          -- the doctype of the subject
274
        relationship  VARCHAR2(128)  NOT NULL,-- the relationship type
275
        object        VARCHAR2(512) NOT NULL, -- the object of the relation
276
        objdoctype    VARCHAR2(128),          -- the doctype of the object
277
        CONSTRAINT xml_relation_uk UNIQUE (docid, subject, relationship, object),
278
        CONSTRAINT xml_relation_docid_fk 
279
                FOREIGN KEY (docid) REFERENCES xml_documents
280
  );
281

    
282
CREATE SEQUENCE xml_relation_id_seq;
283
  
284
CREATE TRIGGER xml_relation_before_insert
285
BEFORE INSERT ON xml_relation FOR EACH ROW
286
BEGIN
287
  SELECT xml_relation_id_seq.nextval
288
    INTO :new.relationid
289
    FROM dual;
290
END;                                   
291
/
292

    
293
/* 
294
 * Table used as Unique ID generator for the uniqueid part of Accession#
295
 */
296
CREATE SEQUENCE accession_number_id_seq;
297
CREATE TABLE accession_number (
298
        uniqueid        NUMBER(20) PRIMARY KEY,
299
        site_code        VARCHAR2(100),
300
        date_created        DATE
301
);
302
CREATE TRIGGER accession_number_before_insert
303
BEFORE INSERT ON accession_number FOR EACH ROW
304
BEGIN
305
  SELECT accession_number_id_seq.nextval
306
    INTO :new.uniqueid
307
    FROM dual;
308
END;                                   
309
/
310

    
311
/* 
312
 * accesssubtree -- table to store access subtree info 
313
 */
314
CREATE TABLE xml_accesssubtree (
315
        docid                VARCHAR2(250),        -- the document id #
316
  rev                 NUMBER(10) DEFAULT 1, --the revision number of the docume
317
  controllevel VARCHAR2(50), -- the level it control -- document or subtree
318
  subtreeid VARCHAR2(250), -- the subtree id 
319
        startnodeid        NUMBER(20),        -- the start node id of access subtree
320
  endnodeid NUMBER(20), -- the end node if of access subtree
321
  CONSTRAINT xml_accesssubtree_docid_fk 
322
                FOREIGN KEY (docid) REFERENCES xml_documents
323
);
324

    
325
/*
326
 * Logging -- table to store metadata and data access log
327
 */
328
CREATE TABLE access_log (
329
  entryid       NUMBER(20),     -- the identifier for the log event
330
  ip_address    VARCHAR2(512),  -- the ip address inititiating the event
331
  principal     VARCHAR2(512),  -- the user initiiating the event
332
  docid         VARCHAR2(250),        -- the document id #
333
  event         VARCHAR2(512),  -- the code symbolizing the event type
334
  date_logged   DATE,           -- the datetime on which the event occurred
335
  CONSTRAINT access_log_pk PRIMARY KEY (entryid)
336
);
337

    
338
CREATE SEQUENCE access_log_id_seq;
339
CREATE TRIGGER access_log_before_insert
340
BEFORE INSERT ON access_log FOR EACH ROW
341
BEGIN
342
  SELECT access_log_id_seq.nextval
343
    INTO :new.entryid
344
    FROM dual;
345
END;