1
|
CREATE TABLE systemMetadata (
|
2
|
guid VARCHAR2(2000), -- the globally unique string identifier
|
3
|
serial_version VARCHAR2(256), --the serial version of the object
|
4
|
date_uploaded DATE, -- the date/time the document was first submitted
|
5
|
rights_holder VARCHAR2(250), --the user who has rights to the document, usually the first persons to upload it
|
6
|
checksum VARCHAR2(512), --the checksum of the doc using the given algorithm (see below)
|
7
|
checksum_algorithm VARCHAR2(250), --the algorithm used to calculate the checksum
|
8
|
origin_member_node VARCHAR2(250), --the member node where the document was first uploaded
|
9
|
authoritive_member_node VARCHAR2(250), --the member node that currently controls the document
|
10
|
date_modified DATE, -- the last date/time that the file was changed
|
11
|
submitter VARCHAR2(256), -- the user who originally submitted the doc
|
12
|
object_format VARCHAR2(256), --the format of the object
|
13
|
size VARCHAR2(256), --the size of the object
|
14
|
archived boolean, -- specifies whether this an archived object
|
15
|
replication_allowed boolean, -- replication allowed
|
16
|
number_replicas NUMBER(8), -- the number of replicas allowed
|
17
|
obsoletes VARCHAR2(2000), -- the identifier of the record that this replaces
|
18
|
obsoleted_by VARCHAR2(2000), -- the identifier of the record that replaces this record
|
19
|
CONSTRAINT systemMetadata_pk
|
20
|
PRIMARY KEY (guid)
|
21
|
)
|
22
|
|
23
|
CREATE TABLE smReplicationPolicy (
|
24
|
guid VARCHAR2(2000), -- the globally unique string identifier of the object that the system metadata describes
|
25
|
member_node VARCHAR(250), -- replication member node
|
26
|
policy VARCHAR2(2000), -- the policy (preferred, blocked, etc...TBD)
|
27
|
CONSTRAINT smReplicationPolicy_fk
|
28
|
FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE
|
29
|
);
|
30
|
|
31
|
CREATE TABLE smReplicationStatus (
|
32
|
guid VARCHAR2(2000), -- the globally unique string identifier of the object that the system metadata describes
|
33
|
member_node VARCHAR(250), -- replication member node
|
34
|
status VARCHAR(250), -- replication status
|
35
|
date_verified DATE, -- the date replication was verified
|
36
|
CONSTRAINT smReplicationStatus_fk
|
37
|
FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE
|
38
|
);
|
39
|
|
40
|
BEGIN
|
41
|
EXECUTE IMMEDIATE 'DROP TABLE identifier';
|
42
|
EXCEPTION
|
43
|
WHEN OTHERS THEN
|
44
|
IF SQLCODE != -942 THEN
|
45
|
RAISE;
|
46
|
END IF;
|
47
|
END;
|
48
|
|
49
|
/*
|
50
|
* Create the new one (DataONE features)
|
51
|
*/
|
52
|
CREATE TABLE identifier (
|
53
|
guid VARCHAR2(2000), -- the globally unique string identifier
|
54
|
docid VARCHAR2(250), -- the local document id #
|
55
|
rev NUMBER(8) -- the revision part of the local identifier
|
56
|
);
|
57
|
|
58
|
/*
|
59
|
* add the nodedatadate column to the tables that need it
|
60
|
*/
|
61
|
ALTER TABLE xml_nodes ADD (nodedatadate TIMESTAMP);
|
62
|
ALTER TABLE xml_nodes_revisions ADD (nodedatadate TIMESTAMP);
|
63
|
ALTER TABLE xml_path_index ADD (nodedatadate TIMESTAMP);
|
64
|
CREATE INDEX xml_path_index_idx5 ON xml_path_index (nodedatadate);
|
65
|
|
66
|
/**
|
67
|
* track the user-agent for the request
|
68
|
*/
|
69
|
ALTER TABLE access_log ADD (user_agent VARCHAR(512));
|
70
|
|
71
|
/*
|
72
|
* Register the new schema
|
73
|
*/
|
74
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
75
|
VALUES ('Schema', '@eml2_1_1namespace@', '/schema/eml-2.1.1/eml.xsd');
|
76
|
|
77
|
/**
|
78
|
* Generate GUIDs for docid.rev
|
79
|
*/
|
80
|
INSERT INTO identifier (docid, rev, guid)
|
81
|
SELECT docid, rev, docid || '.' || rev FROM xml_documents
|
82
|
UNION
|
83
|
SELECT docid, rev, docid || '.' || rev FROM xml_revisions;
|
84
|
--INSERT 0 156644
|
85
|
|
86
|
/**
|
87
|
* Add guid in xml_access table
|
88
|
*/
|
89
|
ALTER TABLE xml_access ADD (guid VARCHAR2(2000));
|
90
|
/**
|
91
|
* Expand accessfileid in xml_access table to hold guids
|
92
|
*/
|
93
|
ALTER TABLE xml_access MODIFY (accessfileid VARCHAR2(2000));
|
94
|
|
95
|
/**
|
96
|
* Upgrade xml_access records to use GUID from identifier table
|
97
|
* NOTE: This duplicates existing access rules for every revision of a document
|
98
|
*/
|
99
|
INSERT INTO xml_access (
|
100
|
guid, principal_name, permission, perm_type, perm_order,
|
101
|
docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
|
102
|
)
|
103
|
SELECT
|
104
|
id.guid, xa.principal_name, xa.permission, xa.perm_type, xa.perm_order,
|
105
|
xa.docid, xa.accessfileid, xa.begin_time, xa.end_time, xa.ticket_count, xa.subtreeid, xa.startnodeid, xa.endnodeid
|
106
|
FROM identifier id, xml_access xa
|
107
|
WHERE id.docid = xa.docid;
|
108
|
|
109
|
/**
|
110
|
* Include inline data access rows -- they have a special guid: 'scope.docid.rev.index'
|
111
|
*/
|
112
|
INSERT INTO xml_access (
|
113
|
guid, principal_name, permission, perm_type, perm_order,
|
114
|
docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
|
115
|
)
|
116
|
SELECT
|
117
|
docid, principal_name, permission, perm_type, perm_order,
|
118
|
docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
|
119
|
FROM xml_access
|
120
|
WHERE docid like '%.%.%.%';
|
121
|
--INSERT 0 18
|
122
|
|
123
|
|
124
|
/**
|
125
|
* Update the accessfileid to use their guid
|
126
|
* NOTE: uses the last revision's guid as the new value for accessfileid
|
127
|
* uses a temporary table
|
128
|
**/
|
129
|
CREATE TABLE max_identifier (guid VARCHAR2(2000), docid VARCHAR2(250), rev NUMBER(8));
|
130
|
|
131
|
/** insert the max rev identifier for each document **/
|
132
|
INSERT INTO max_identifier (docid, rev, guid)
|
133
|
SELECT docid, MAX(rev), docid || '.' || MAX(rev)
|
134
|
FROM identifier
|
135
|
GROUP BY docid;
|
136
|
--INSERT 0 57841
|
137
|
|
138
|
/** create some indexes to speed up the join **/
|
139
|
CREATE INDEX maxid_docid_index ON max_identifier (docid);
|
140
|
CREATE INDEX maxid_guid_index ON max_identifier (guid);
|
141
|
CREATE INDEX accessfileid_index on xml_access (accessfileid);
|
142
|
CREATE INDEX xml_access_guid_index on xml_access (guid);
|
143
|
|
144
|
UPDATE xml_access xa
|
145
|
SET accessfileid = (SELECT maxid.guid
|
146
|
FROM max_identifier maxid
|
147
|
WHERE xa.accessfileid = maxid.docid
|
148
|
AND xa.guid IS NOT null);
|
149
|
--UPDATE 310427
|
150
|
|
151
|
DROP INDEX maxid_docid_index;
|
152
|
DROP INDEX maxid_guid_index;
|
153
|
DROP INDEX accessfileid_index;
|
154
|
DROP INDEX xml_access_guid_index;
|
155
|
|
156
|
DROP TABLE max_identifier;
|
157
|
|
158
|
/**
|
159
|
* Remove old access rules
|
160
|
*/
|
161
|
DELETE FROM xml_access WHERE guid is null;
|
162
|
--DELETE 105432
|
163
|
|
164
|
/**
|
165
|
* clean up the xml_access table
|
166
|
*/
|
167
|
ALTER TABLE xml_access DROP (docid);
|
168
|
|
169
|
|
170
|
/**
|
171
|
* expand xml_path_index 'path' column to hold larger strings
|
172
|
*/
|
173
|
ALTER TABLE xml_path_index MODIFY ( path VARCHAR2(4000) );
|
174
|
|
175
|
/**
|
176
|
* include 2.0.0beta4 DTD
|
177
|
*/
|
178
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
179
|
VALUES ('DTD', '-//ecoinformatics.org//eml-access-@eml-beta4-version@//EN',
|
180
|
'/dtd/eml-access-@eml-beta4-version@.dtd');
|
181
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
182
|
VALUES ('DTD', '-//ecoinformatics.org//eml-attribute-@eml-beta4-version@//EN',
|
183
|
'/dtd/eml-attribute-@eml-beta4-version@.dtd');
|
184
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
185
|
VALUES ('DTD', '-//ecoinformatics.org//eml-constraint-@eml-beta4-version@//EN',
|
186
|
'/dtd/eml-constraint-@eml-beta4-version@.dtd');
|
187
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
188
|
VALUES ('DTD', '-//ecoinformatics.org//eml-coverage-@eml-beta4-version@//EN',
|
189
|
'/dtd/eml-coverage-@eml-beta4-version@.dtd');
|
190
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
191
|
VALUES ('DTD', '-//ecoinformatics.org//eml-dataset-@eml-beta4-version@//EN',
|
192
|
'/dtd/eml-dataset-@eml-beta4-version@.dtd');
|
193
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
194
|
VALUES ('DTD', '-//ecoinformatics.org//eml-entity-@eml-beta4-version@//EN',
|
195
|
'/dtd/eml-entity-@eml-beta4-version@.dtd');
|
196
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
197
|
VALUES ('DTD', '-//ecoinformatics.org//eml-literature-@eml-beta4-version@//EN',
|
198
|
'/dtd/eml-literature-@eml-beta4-version@.dtd');
|
199
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
200
|
VALUES ('DTD', '-//ecoinformatics.org//eml-physical-@eml-beta4-version@//EN',
|
201
|
'/dtd/eml-physical-@eml-beta4-version@.dtd');
|
202
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
203
|
VALUES ('DTD', '-//ecoinformatics.org//eml-project-@eml-beta4-version@//EN',
|
204
|
'/dtd/eml-project-@eml-beta4-version@.dtd');
|
205
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
206
|
VALUES ('DTD', '-//ecoinformatics.org//eml-protocol-@eml-beta4-version@//EN',
|
207
|
'/dtd/eml-protocol-@eml-beta4-version@.dtd');
|
208
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
209
|
VALUES ('DTD', '-//ecoinformatics.org//eml-software-@eml-beta4-version@//EN',
|
210
|
'/dtd/eml-software-@eml-beta4-version@.dtd');
|
211
|
|
212
|
/*
|
213
|
* update the database version
|
214
|
*/
|
215
|
UPDATE db_version SET status=0;
|
216
|
|
217
|
INSERT INTO db_version (version, status, date_created)
|
218
|
VALUES ('2.0.0', 1, CURRENT_DATE);
|