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 systemMetadataReplicationPolicy (
|
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 systemMetadataReplicationPolicy_fk
|
28
|
FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE
|
29
|
);
|
30
|
|
31
|
CREATE TABLE systemMetadataReplicationStatus (
|
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 systemMetadataReplicationStatus_fk
|
37
|
FOREIGN KEY (guid) REFERENCES systemMetadata DEFERRABLE
|
38
|
);
|
39
|
|
40
|
DROP TABLE IF EXISTS identifier;
|
41
|
|
42
|
CREATE TABLE identifier (
|
43
|
guid VARCHAR2(2000), -- the globally unique string identifier
|
44
|
docid VARCHAR2(250), -- the local document id #
|
45
|
rev NUMBER(8) -- the revision part of the local identifier
|
46
|
);
|
47
|
|
48
|
/**
|
49
|
* track the user-agent for the request
|
50
|
*/
|
51
|
ALTER TABLE access_log ADD COLUMN user_agent VARCHAR2(512);
|
52
|
|
53
|
/*
|
54
|
* add the nodedatadate column to xml_nodes
|
55
|
* TODO: load the data into it (java?)
|
56
|
*/
|
57
|
ALTER TABLE xml_nodes ADD COLUMN nodedatadate TIMESTAMP;
|
58
|
ALTER TABLE xml_nodes_revisions ADD COLUMN nodedatadate TIMESTAMP;
|
59
|
ALTER TABLE xml_path_index ADD COLUMN nodedatadate TIMESTAMP;
|
60
|
CREATE INDEX xml_path_index_idx4 ON xml_path_index (nodedatadate);
|
61
|
|
62
|
/*
|
63
|
* Register the new schema
|
64
|
*/
|
65
|
INSERT INTO xml_catalog (entry_type, public_id, system_id)
|
66
|
VALUES ('Schema', '@eml2_1_1namespace@', '/schema/eml-2.1.1/eml.xsd');
|
67
|
|
68
|
/**
|
69
|
* Generate GUIDs for docid.rev
|
70
|
*/
|
71
|
INSERT INTO identifier (docid, rev, guid)
|
72
|
SELECT docid, rev, docid || '.' || rev FROM xml_documents
|
73
|
UNION
|
74
|
SELECT docid, rev, docid || '.' || rev FROM xml_revisions;
|
75
|
/*
|
76
|
* Allow guid in xml_access table (for system metadata)
|
77
|
*/
|
78
|
ALTER TABLE xml_access ADD COLUMN guid VARCHAR2(2000);
|
79
|
/**
|
80
|
* Expand accessfileid in xml_access table to hold guids
|
81
|
*/
|
82
|
ALTER TABLE xml_access ALTER COLUMN accessfileid TYPE VARCHAR2(2000);
|
83
|
|
84
|
|
85
|
/**
|
86
|
* Upgrade xml_access records to use GUID from identifier table
|
87
|
* NOTE: This duplicates existing access rules for every revision of a document
|
88
|
*/
|
89
|
INSERT INTO xml_access (
|
90
|
guid, principal_name, permission, perm_type, perm_order,
|
91
|
docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
|
92
|
)
|
93
|
SELECT
|
94
|
id.guid, xa.principal_name, xa.permission, xa.perm_type, xa.perm_order,
|
95
|
xa.docid, xa.accessfileid, xa.begin_time, xa.end_time, xa.ticket_count, xa.subtreeid, xa.startnodeid, xa.endnodeid
|
96
|
FROM identifier id, xml_access xa
|
97
|
WHERE id.docid = xa.docid;
|
98
|
|
99
|
/**
|
100
|
* Include inline data access rows -- they have a special guid: 'scope.docid.rev.index'
|
101
|
*/
|
102
|
INSERT INTO xml_access (
|
103
|
guid, principal_name, permission, perm_type, perm_order,
|
104
|
docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
|
105
|
)
|
106
|
SELECT
|
107
|
docid, principal_name, permission, perm_type, perm_order,
|
108
|
docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
|
109
|
FROM xml_access
|
110
|
WHERE docid like '%.%.%.%';
|
111
|
|
112
|
/**
|
113
|
* Update the accessfileid to use guid
|
114
|
* NOTE: uses the last revision's guid as the new accessfileid
|
115
|
*/
|
116
|
CREATE TABLE max_identifier (guid VARCHAR2(2000), docid VARCHAR2(250), rev NUMBER(8));
|
117
|
|
118
|
/** insert the max rev identifier for each document **/
|
119
|
INSERT INTO max_identifier (docid, rev, guid)
|
120
|
SELECT docid, MAX(rev), docid || '.' || MAX(rev)
|
121
|
FROM identifier
|
122
|
GROUP BY docid;
|
123
|
|
124
|
/** create some indexes to speed up the join **/
|
125
|
CREATE INDEX maxid_docid_index ON max_identifier (docid);
|
126
|
CREATE INDEX maxid_guid_index ON max_identifier (docid);
|
127
|
CREATE INDEX accessfileid_index on xml_access (accessfileid);
|
128
|
CREATE INDEX xml_access_guid_index on xml_access (guid);
|
129
|
|
130
|
/** only need to join on docid since there is a single row for the max docid **/
|
131
|
UPDATE xml_access xa
|
132
|
SET accessfileid = maxid.guid
|
133
|
FROM max_identifier maxid
|
134
|
WHERE xa.accessfileid = maxid.docid
|
135
|
AND xa.guid IS NOT null;
|
136
|
|
137
|
DROP INDEX maxid_docid_index;
|
138
|
DROP INDEX maxid_guid_index;
|
139
|
DROP INDEX accessfileid_index;
|
140
|
DROP INDEX xml_access_guid_index;
|
141
|
|
142
|
DROP TABLE max_identifier;
|
143
|
|
144
|
/**
|
145
|
* Remove old access rules
|
146
|
*/
|
147
|
DELETE FROM xml_access WHERE guid is null;
|
148
|
|
149
|
/**
|
150
|
* clean up the xml_access table
|
151
|
*/
|
152
|
ALTER TABLE xml_access DROP COLUMN docid;
|
153
|
|
154
|
/**
|
155
|
* expand xml_path_index 'path' column to hold larger strings
|
156
|
*/
|
157
|
ALTER TABLE xml_path_index MODIFY ( path VARCHAR2(4000) );
|
158
|
|
159
|
/*
|
160
|
* update the database version
|
161
|
*/
|
162
|
UPDATE db_version SET status=0;
|
163
|
|
164
|
INSERT INTO db_version (version, status, date_created)
|
165
|
VALUES ('2.0.0', 1, CURRENT_DATE);
|