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-11-01 11:31:31 -0800 (Tue, 01 Nov 2005) $'
|
8
|
* '$Revision: 2710 $'
|
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
|
/*
|
27
|
* Index of Paths - table to store nodes with paths specified by userst in metacat.properties
|
28
|
*/
|
29
|
CREATE TABLE xml_path_index (
|
30
|
nodeid NUMBER(20), -- the unique node id
|
31
|
docid VARCHAR2(250), -- index to the document id
|
32
|
path VARCHAR2(1000), -- precomputed path through tree
|
33
|
nodedata VARCHAR2(4000), -- the data for this node e.g.,
|
34
|
nodedatanumerical NUMBER(20), -- the data for this node if
|
35
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
36
|
CONSTRAINT xml_path_index_pk PRIMARY KEY (nodeid),
|
37
|
CONSTRAINT xml_path_index_docid_fk FOREIGN KEY (docid) REFERENCES xml_documents
|
38
|
);
|
39
|
|
40
|
|
41
|
/*
|
42
|
* create sequence an trigger
|
43
|
*/
|
44
|
CREATE SEQUENCE xml_path_index_id_seq;
|
45
|
CREATE TRIGGER xml_path_index_before_insert
|
46
|
BEFORE INSERT ON xml_path_index FOR EACH ROW
|
47
|
BEGIN
|
48
|
SELECT xml_path_index_id_seq.nextval
|
49
|
INTO :new.nodeid
|
50
|
FROM dual;
|
51
|
END;
|
52
|
/
|
53
|
|
54
|
|
55
|
/**
|
56
|
* Index of the path, nodedata, nodedatanumerical in xml_path_index
|
57
|
*/
|
58
|
CREATE INDEX xml_path_index_idx1 ON xml_path_index (path);
|
59
|
CREATE INDEX xml_path_index_idx2 ON xml_path_index (nodedata);
|
60
|
CREATE INDEX xml_path_index_idx3 ON xml_path_index (nodedatanumerical);
|
61
|
|
62
|
|
63
|
|
64
|
/**
|
65
|
* Create the xml_nodes_revisions table
|
66
|
* to store nodes from xml_nodes which
|
67
|
* are of old revisions and deleted document
|
68
|
*/
|
69
|
|
70
|
CREATE TABLE xml_nodes_revisions (
|
71
|
nodeid NUMBER(20), -- the unique node id (pk)
|
72
|
nodeindex NUMBER(10), -- order of nodes within parent
|
73
|
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI,
|
74
|
-- ELEMENT, ATTRIBUTE, TEXT)
|
75
|
nodename VARCHAR2(250), -- the name of an element or attribute
|
76
|
nodeprefix VARCHAR2(50), -- the namespace prefix of an element
|
77
|
-- or attribute
|
78
|
nodedata VARCHAR2(4000), -- the data for this node (e.g.,
|
79
|
-- for TEXT it is the content)
|
80
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
81
|
rootnodeid NUMBER(20), -- index of the root node of this tree
|
82
|
docid VARCHAR2(250), -- index to the document id
|
83
|
date_created DATE,
|
84
|
date_updated DATE,
|
85
|
nodedatanumerical NUMBER, -- the data for this node if
|
86
|
-- it is a number
|
87
|
CONSTRAINT xml_nodes_revisions_pk PRIMARY KEY (nodeid),
|
88
|
CONSTRAINT xml_nodes_revisions_root_fk
|
89
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions,
|
90
|
CONSTRAINT xml_nodes_revisions_parent_fk
|
91
|
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes_revisions
|
92
|
);
|
93
|
|
94
|
|
95
|
/**
|
96
|
* Indexes of rootnodeid, parentnodeid, and nodename in xml_nodes_revision
|
97
|
*/
|
98
|
CREATE INDEX xml_nodes_revisions_idx1 ON xml_nodes_revisions (rootnodeid);
|
99
|
CREATE INDEX xml_nodes_revisions_idx2 ON xml_nodes_revisions (parentnodeid);
|
100
|
CREATE INDEX xml_nodes_revisions_idx3 ON xml_nodes_revisions (nodename);
|
101
|
|
102
|
|
103
|
/**
|
104
|
* Drop the constraint from xml_revisions which points to xml_nodes
|
105
|
*/
|
106
|
ALTER TABLE xml_revisions DROP CONSTRAINT xml_revisions_root_fk;
|
107
|
|
108
|
|
109
|
/**
|
110
|
* Copy the nodes from xml_nodes to xml_nodes_revisions for old revisions
|
111
|
* of the documents and deleted documents
|
112
|
*/
|
113
|
INSERT INTO xml_nodes_revisions (nodeid, nodeindex, nodetype,
|
114
|
nodename, nodeprefix, nodedata, parentnodeid, rootnodeid,
|
115
|
docid, date_created, date_updated, nodedatanumerical)
|
116
|
SELECT * FROM xml_nodes WHERE rootnodeid NOT IN
|
117
|
(SELECT rootnodeid from xml_documents where rootnodeid is not NULL);
|
118
|
|
119
|
|
120
|
/**
|
121
|
* Create the key constraint in xml_revisions which points to
|
122
|
* xml_nodes_revisions
|
123
|
*/
|
124
|
ALTER TABLE xml_revisions ADD CONSTRAINT xml_revisions_root_fk
|
125
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes_revisions (nodeid);
|
126
|
|
127
|
|
128
|
/**
|
129
|
* Delete the records from xml_index table which point to old revisions in xml_index
|
130
|
* This is possible for documents for which the indexing thread failed during UPDATE
|
131
|
*/
|
132
|
|
133
|
DELETE FROM xml_index WHERE nodeid IN (SELECT nodeid FROM xml_nodes WHERE
|
134
|
rootnodeid NOT IN (SELECT rootnodeid FROM xml_documents WHERE rootnodeid IS NOT NULL));
|
135
|
|
136
|
/**
|
137
|
* Delete the records from xml_nodes which were transfered to xml_nodes_revisions
|
138
|
*/
|
139
|
|
140
|
/**
|
141
|
* Below given statement takes a lot of time to excute
|
142
|
*
|
143
|
* DELETE FROM xml_nodes WHERE rootnodeid NOT IN
|
144
|
* (SELECT rootnodeid from xml_documents where rootnodeid is not NULL);
|
145
|
*
|
146
|
* Hence.....
|
147
|
*/
|
148
|
|
149
|
|
150
|
/**
|
151
|
* Drop the xml_nodes primark key....
|
152
|
*/
|
153
|
ALTER TABLE xml_nodes DROP CONSTRAINT xml_nodes_pk CASCADE;
|
154
|
|
155
|
|
156
|
/** rename xml_nodes to xml_nodes_2 */
|
157
|
ALTER TABLE xml_nodes RENAME TO xml_nodes_2;
|
158
|
|
159
|
/** create a new xml_nodes table with new primary and foreign keys*/
|
160
|
CREATE TABLE xml_nodes (
|
161
|
nodeid NUMBER(20), -- the unique node id (pk)
|
162
|
nodeindex NUMBER(10), -- order of nodes within parent
|
163
|
nodetype VARCHAR2(20), -- type (DOCUMENT, COMMENT, PI,
|
164
|
-- ELEMENT, ATTRIBUTE, TEXT)
|
165
|
nodename VARCHAR2(250), -- the name of an element or attribute
|
166
|
nodeprefix VARCHAR2(50), -- the namespace prefix of an element
|
167
|
-- or attribute
|
168
|
nodedata VARCHAR2(4000), -- the data for this node (e.g.,
|
169
|
-- for TEXT it is the content)
|
170
|
parentnodeid NUMBER(20), -- index of the parent of this node
|
171
|
rootnodeid NUMBER(20), -- index of the root node of this tree
|
172
|
docid VARCHAR2(250), -- index to the document id
|
173
|
date_created DATE,
|
174
|
date_updated DATE,
|
175
|
nodedatanumerical NUMBER, -- the data for this node if
|
176
|
-- it is a number
|
177
|
CONSTRAINT xml_nodes_pk PRIMARY KEY (nodeid),
|
178
|
CONSTRAINT xml_nodes_root_fk
|
179
|
FOREIGN KEY (rootnodeid) REFERENCES xml_nodes,
|
180
|
CONSTRAINT xml_nodes_parent_fk
|
181
|
FOREIGN KEY (parentnodeid) REFERENCES xml_nodes
|
182
|
);
|
183
|
|
184
|
/** copy nodes from xml_nodes_2 to xml_nodes */
|
185
|
INSERT INTO xml_nodes (nodeid, nodeindex, nodetype, nodename, nodeprefix, nodedata, parentnodeid, rootnodeid, docid, date_created, date_updated, nodedatanumerical) SELECT n.nodeid, n.nodeindex, n.nodetype, n.nodename, n.nodeprefix, n.nodedata, n.parentnodeid, n.rootnodeid, n.docid, n.date_created, n.date_updated, n.nodedatanumerical FROM xml_nodes_2 n, xml_nodes_revisions r WHERE n.rootnodeid = r.rootnodeid(+) AND r.rootnodeid is NULL;
|
186
|
|
187
|
|
188
|
/** Drop old indexes **/
|
189
|
DROP INDEX xml_nodes_idx1;
|
190
|
DROP INDEX xml_nodes_idx2;
|
191
|
DROP INDEX xml_nodes_idx3;
|
192
|
|
193
|
/** Create new indexes **/
|
194
|
CREATE INDEX xml_nodes_idx1 ON xml_nodes (rootnodeid);
|
195
|
CREATE INDEX xml_nodes_idx2 ON xml_nodes (parentnodeid);
|
196
|
CREATE INDEX xml_nodes_idx3 ON xml_nodes (nodename);
|
197
|
|
198
|
/** Add constaints which were deleted before moving xml_nodes to xml_nodes_2 */
|
199
|
ALTER TABLE xml_documents ADD CONSTRAINT xml_documents_root_fk FOREIGN KEY (rootnodeid) REFERENCES xml_nodes;
|
200
|
ALTER TABLE xml_index ADD CONSTRAINT xml_index_nodeid_fk FOREIGN KEY (nodeid) REFERENCES xml_nodes;
|
201
|
|
202
|
/** Drop xml_nodes_2 table */
|
203
|
DROP TABLE xml_nodes_2;
|
204
|
|
205
|
/** Done */
|
206
|
|
207
|
|