Project

General

Profile

metacat / src / xmltables.sql @ 759

1
/*
2
 * xmltables.sql -- Create or replace tables for storing XML in the db
3
 *
4
 *      Purpose: creates tables needed for XML database
5
 * 
6
 *      Created: 12 September 1999
7
 *       Author: Matt Jones
8
 * Organization: National Center for Ecological Analysis and Synthesis
9
 *    Copyright: 2000 Regents of the University of California and the
10
 *               National Center for Ecological Analysis and Synthesis
11
 *  For Details: http://www.nceas.ucsb.edu/
12
 *    File Info: '$Id: xmltables.sql 759 2001-06-01 00:26:32Z bojilova $'
13
 *
14
 */
15

    
16
/*
17
 * Drop all of the objects in proper order
18
 */
19
set echo off
20

    
21
DROP SEQUENCE xml_nodes_id_seq;
22
DROP SEQUENCE xml_revisions_id_seq;
23
DROP SEQUENCE xml_catalog_id_seq;
24
DROP SEQUENCE xml_relation_id_seq;
25
DROP SEQUENCE xml_replication_id_seq;
26
DROP SEQUENCE accnum_uniqueid_seq;
27
DROP SEQUENCE xml_documents_id_seq;
28
DROP SEQUENCE accession_number_id_seq;
29
               
30
/* Drop triggers are not necessary */
31
DROP TRIGGER xml_nodes_before_insert;
32
DROP TRIGGER xml_revisions_before_insert;
33
DROP TRIGGER xml_catalog_before_insert;
34
DROP TRIGGER xml_relation_before_insert;
35
DROP TRIGGER xml_replication_before_insert;
36
DROP TRIGGER accession_number_before_insert;
37

    
38
DROP TABLE xml_index;
39
DROP TABLE xml_access;
40
DROP TABLE xml_revisions;
41
DROP TABLE xml_relation;
42
DROP TABLE xml_documents;
43
DROP TABLE xml_nodes;
44
DROP TABLE xml_replication;
45
DROP TABLE xml_catalog;
46
DROP TABLE accession_number;
47

    
48
/*
49
 *Replication -- table to store servers that metacat is replicated to
50
 */
51
CREATE TABLE xml_replication (
52
  serverid      NUMBER(20),
53
  server        VARCHAR2(512),
54
  last_checked  DATE,
55
  replicate     NUMBER(1), 
56
  CONSTRAINT xml_replication_pk PRIMARY KEY (serverid)
57
);  
58
  
59
CREATE SEQUENCE xml_replication_id_seq;
60
CREATE TRIGGER xml_replication_before_insert
61
BEFORE INSERT ON xml_replication FOR EACH ROW
62
BEGIN
63
  SELECT xml_replication_id_seq.nextval
64
    INTO :new.serverid
65
    FROM dual;
66
END;
67
/
68

    
69
INSERT INTO xml_replication (serverid, server, replicate) VALUES ('1', 'localhost', '0');
70

    
71
/* 
72
 * Nodes -- table to store XML Nodes (both elements and attributes)
73
 */
74
CREATE SEQUENCE xml_nodes_id_seq;
75
CREATE TABLE xml_nodes (
76
        nodeid                NUMBER(20),        -- the unique node id (pk)
77
        nodeindex        NUMBER(10),        -- order of nodes within parent
78
        nodetype        VARCHAR2(20),        -- type (DOCUMENT, COMMENT, PI,
79
                                        -- ELEMENT, ATTRIBUTE, TEXT)
80
        nodename        VARCHAR2(250),        -- the name of an element or attribute
81
        nodedata        VARCHAR2(4000), -- the data for this node (e.g., 
82
                                        -- for TEXT it is the content)
83
        parentnodeid        NUMBER(20),        -- index of the parent of this node
84
        rootnodeid        NUMBER(20),        -- index of the root node of this tree
85
        docid                VARCHAR2(250),        -- index to the document id
86
        date_created        DATE,
87
        date_updated        DATE,
88
   CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
89
   CONSTRAINT xml_nodes_root_fk 
90
                FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
91
   CONSTRAINT xml_nodes_parent_fk 
92
                FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
93
);
94
CREATE TRIGGER xml_nodes_before_insert
95
BEFORE INSERT ON xml_nodes FOR EACH ROW
96
BEGIN
97
  SELECT xml_nodes_id_seq.nextval
98
    INTO :new.nodeid
99
    FROM dual;     
100
END;    
101
/
102
                               
103
/* 
104
 * Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes
105
 */
106
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
107
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
108
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
109

    
110
/* 
111
 * XML Catalog -- table to store all external sources for XML documents
112
 */
113
CREATE TABLE xml_catalog (
114
        catalog_id        NUMBER(20),        -- the id for this catalog entry
115
        entry_type        VARCHAR2(500),        -- the type of this catalog entry
116
                                        -- (e.g., DTD, XSD, XSL)
117
        source_doctype        VARCHAR2(500),        -- the source public_id for transforms
118
        target_doctype        VARCHAR2(500),        -- the target public_id for transforms
119
        public_id        VARCHAR2(500),        -- the unique id for this type
120
        system_id        VARCHAR2(1000),        -- the local location of the object
121
   CONSTRAINT xml_catalog_pk PRIMARY KEY (catalog_id),
122
   CONSTRAINT xml_catalog_uk UNIQUE 
123
                (entry_type, source_doctype, target_doctype, public_id)
124
);
125

    
126
CREATE SEQUENCE xml_catalog_id_seq;
127

    
128
CREATE TRIGGER xml_catalog_before_insert
129
BEFORE INSERT ON xml_catalog FOR EACH ROW
130
BEGIN
131
  SELECT xml_catalog_id_seq.nextval
132
    INTO :new.catalog_id
133
    FROM dual;
134
END;
135
/
136

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

    
162
/* 
163
 * Index of <docid,doctype> in xml_document
164
 */
165
CREATE INDEX xml_documents_idx1 ON xml_documents (docid, doctype);
166

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

    
194
CREATE SEQUENCE xml_revisions_id_seq;
195

    
196
CREATE TRIGGER xml_revisions_before_insert
197
BEFORE INSERT ON xml_revisions FOR EACH ROW
198
BEGIN
199
  SELECT xml_revisions_id_seq.nextval
200
    INTO :new.revisionid
201
    FROM dual;
202
END;
203
/
204

    
205
/* 
206
 * ACL -- table to store ACL for XML documents by principals
207
 */
208
CREATE TABLE xml_access (
209
        docid                VARCHAR2(250),        -- the document id #
210
        accessfileid        VARCHAR2(250),        -- the document id # for the access file
211
        principal_name        VARCHAR2(100),        -- name of user, group, etc.
212
        permission        NUMBER(1),        -- "read", "write", "all"
213
        perm_type        VARCHAR2(32),        -- "allowed" or "denied"
214
        perm_order        VARCHAR2(32),        -- "allow first" or "deny first"
215
        begin_time        DATE,                -- the time that permission begins
216
        end_time        DATE,                -- the time that permission ends
217
        ticket_count        NUMBER(5),        -- ticket counter for that permission
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

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

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

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

    
260
CREATE SEQUENCE xml_relation_id_seq;
261
  
262
CREATE TRIGGER xml_relation_before_insert
263
BEFORE INSERT ON xml_relation FOR EACH ROW
264
BEGIN
265
  SELECT xml_relation_id_seq.nextval
266
    INTO :new.relationid
267
    FROM dual;
268
END;                                   
269
/
270

    
271
/* 
272
 * Table used as Unique ID generator for the uniqueid part of Accession#
273
 */
274
CREATE SEQUENCE accession_number_id_seq;
275
CREATE TABLE accession_number (
276
        uniqueid        NUMBER(20) PRIMARY KEY,
277
        site_code        VARCHAR2(100),
278
        date_created        DATE
279
);
280
CREATE TRIGGER accession_number_before_insert
281
BEFORE INSERT ON accession_number FOR EACH ROW
282
BEGIN
283
  SELECT accession_number_id_seq.nextval
284
    INTO :new.uniqueid
285
    FROM dual;
286
END;                                   
287
/
288