1
|
/**
|
2
|
* Restore archived documents
|
3
|
*/
|
4
|
|
5
|
/*
|
6
|
* Gather most recent docids that:
|
7
|
* - have access_log event='delete' by the CN
|
8
|
* - are obsoleted by a newer version
|
9
|
* Then we know the current version should be restored
|
10
|
*/
|
11
|
|
12
|
/* Find the most recent version by traversing system metadata
|
13
|
* see: http://www.postgresql.org/docs/8.4/static/queries-with.html
|
14
|
*/
|
15
|
DROP TABLE IF EXISTS current_documents;
|
16
|
WITH RECURSIVE q AS
|
17
|
(
|
18
|
SELECT id.guid, sm.obsoleted_by
|
19
|
FROM access_log al, identifier id, systemmetadata sm
|
20
|
WHERE al.event = 'delete'
|
21
|
AND al.date_logged >= '20140101'
|
22
|
AND al.principal LIKE '%urn:node:CN%'
|
23
|
AND al.docid = id.docid || '.' || id.rev
|
24
|
AND id.guid = sm.guid
|
25
|
AND sm.obsoleted_by IS NOT null
|
26
|
UNION ALL
|
27
|
SELECT newer.guid, newer.obsoleted_by
|
28
|
FROM systemMetadata newer
|
29
|
JOIN q
|
30
|
ON q.obsoleted_by = newer.guid
|
31
|
)
|
32
|
SELECT guid, obsoleted_by
|
33
|
INTO current_documents
|
34
|
FROM q
|
35
|
WHERE obsoleted_by is null
|
36
|
ORDER BY guid;
|
37
|
|
38
|
/**
|
39
|
* Gather the details of the documents to restore
|
40
|
*/
|
41
|
DROP TABLE IF EXISTS restore_documents;
|
42
|
CREATE TABLE restore_documents (
|
43
|
docid VARCHAR(250),
|
44
|
rev INT8,
|
45
|
rootnodeid INT8,
|
46
|
guid text
|
47
|
);
|
48
|
INSERT INTO restore_documents (
|
49
|
docid,
|
50
|
rev,
|
51
|
rootnodeid,
|
52
|
guid
|
53
|
)
|
54
|
SELECT
|
55
|
x.docid,
|
56
|
x.rev,
|
57
|
x.rootnodeid,
|
58
|
id.guid
|
59
|
FROM current_documents cd,
|
60
|
xml_revisions x,
|
61
|
identifier id
|
62
|
WHERE x.docid = id.docid
|
63
|
AND x.rev = id.rev
|
64
|
AND id.guid = cd.guid;
|
65
|
|
66
|
-- look at them
|
67
|
SELECT *
|
68
|
FROM restore_documents;
|
69
|
|
70
|
--STOP HERE WHEN TESTING
|
71
|
|
72
|
/* Move xml_nodes_revisions back into xml_nodes for the affected docids
|
73
|
*/
|
74
|
INSERT INTO xml_nodes
|
75
|
(nodeid, nodeindex, nodetype, nodename, nodeprefix,
|
76
|
nodedata, parentnodeid, rootnodeid, docid, date_created,
|
77
|
date_updated, nodedatanumerical, nodedatadate)
|
78
|
SELECT
|
79
|
nodeid, nodeindex, nodetype, nodename, nodeprefix,
|
80
|
nodedata, parentnodeid, x.rootnodeid, x.docid, date_created,
|
81
|
date_updated, nodedatanumerical, nodedatadate
|
82
|
FROM xml_nodes_revisions x, restore_documents rd
|
83
|
WHERE x.rootnodeid = rd.rootnodeid;
|
84
|
|
85
|
/* Move xml_revisions back into xml_documents for the affected docids
|
86
|
*/
|
87
|
INSERT INTO xml_documents
|
88
|
(docid, rootnodeid, docname, doctype,
|
89
|
user_owner, user_updated, date_created, date_updated,
|
90
|
server_location, rev, public_access, catalog_id)
|
91
|
SELECT
|
92
|
x.docid, x.rootnodeid, docname, doctype,
|
93
|
user_owner, user_updated , date_created, date_updated,
|
94
|
server_location, x.rev, public_access, catalog_id
|
95
|
FROM xml_revisions x, restore_documents rd
|
96
|
WHERE x.rootnodeid = rd.rootnodeid;
|
97
|
|
98
|
/* Remove the records from revisions
|
99
|
* Order matters here because of foreign key constraints
|
100
|
*/
|
101
|
DELETE FROM xml_revisions x
|
102
|
USING restore_documents rd
|
103
|
WHERE x.rootnodeid = rd.rootnodeid;
|
104
|
|
105
|
DELETE FROM xml_nodes_revisions x
|
106
|
USING restore_documents rd
|
107
|
WHERE x.rootnodeid = rd.rootnodeid;
|
108
|
|
109
|
/* Ensure ALL previous revisions of docids
|
110
|
* that have been obsoleted_by something else
|
111
|
* do not also have archived=true flag set
|
112
|
* (Avoids encountering this issue again)
|
113
|
*/
|
114
|
|
115
|
/* Check the numbers
|
116
|
*/
|
117
|
SELECT count(id.guid)
|
118
|
FROM xml_revisions x,
|
119
|
identifier id,
|
120
|
systemMetadata sm
|
121
|
WHERE x.docid = id.docid
|
122
|
AND x.rev = id.rev
|
123
|
AND id.guid = sm.guid
|
124
|
AND sm.obsoleted_by IS NOT null
|
125
|
AND sm.archived = 'true';
|
126
|
|
127
|
/*Do the update on xml_revisions
|
128
|
*/
|
129
|
UPDATE systemMetadata sm
|
130
|
SET sm.archived = false
|
131
|
FROM xml_revisions x,
|
132
|
identifier id
|
133
|
WHERE x.docid = id.docid
|
134
|
AND x.rev = id.rev
|
135
|
AND id.guid = sm.guid
|
136
|
AND sm.obsoleted_by IS NOT null
|
137
|
AND sm.archived = 'true';
|
138
|
|
139
|
/**
|
140
|
* Check numbers in xml_documents
|
141
|
*/
|
142
|
SELECT count(id.guid)
|
143
|
FROM xml_documents x,
|
144
|
identifier id,
|
145
|
systemMetadata sm
|
146
|
WHERE x.docid = id.docid
|
147
|
AND x.rev = id.rev
|
148
|
AND id.guid = sm.guid
|
149
|
AND sm.obsoleted_by IS NOT null
|
150
|
AND sm.archived = 'true';
|
151
|
|
152
|
/*Do the update on xml_documents
|
153
|
*/
|
154
|
UPDATE systemMetadata sm
|
155
|
SET sm.archived = false
|
156
|
FROM xml_documents x,
|
157
|
identifier id
|
158
|
WHERE x.docid = id.docid
|
159
|
AND x.rev = id.rev
|
160
|
AND id.guid = sm.guid
|
161
|
AND sm.obsoleted_by IS NOT null
|
162
|
AND sm.archived = 'true';
|
163
|
|
164
|
/* Clean up
|
165
|
*/
|
166
|
DROP TABLE IF EXISTS current_documents;
|
167
|
DROP TABLE IF EXISTS restore_documents;
|
168
|
|
169
|
/*
|
170
|
* update the database version
|
171
|
*/
|
172
|
UPDATE db_version SET status=0;
|
173
|
|
174
|
INSERT INTO db_version (version, status, date_created)
|
175
|
VALUES ('2.4.0', 1, CURRENT_DATE);
|