Revision 7292
Added by ben leinfelder over 12 years ago
src/delete_all_by_pid.sql | ||
---|---|---|
1 |
/** |
|
2 |
* This function removes all traces of an object identified by the given {pid}. |
|
3 |
* NOTE: for complete removal, the object should also be deleted from the filesystem. |
|
4 |
*/ |
|
5 |
CREATE OR REPLACE FUNCTION delete_all(pid text) RETURNS VOID AS $$ |
|
6 |
DECLARE |
|
7 |
v_docid text; |
|
8 |
v_rev integer; |
|
9 |
v_doctype text; |
|
10 |
deleted_count integer; |
|
11 |
BEGIN |
|
12 |
SELECT INTO v_docid docid FROM identifier WHERE guid = pid; |
|
13 |
SELECT INTO v_rev rev FROM identifier WHERE guid = pid; |
|
14 |
|
|
15 |
SELECT INTO v_doctype doctype FROM xml_documents WHERE docid = v_docid and rev = v_rev; |
|
16 |
IF v_doctype IS NULL THEN |
|
17 |
SELECT INTO v_doctype doctype FROM xml_revisions WHERE docid = v_docid and rev = v_rev; |
|
18 |
END IF; |
|
19 |
|
|
20 |
RAISE NOTICE 'Processing pid: %, which is docid: %.%, with doctype: %', pid, v_docid, v_rev, v_doctype; |
|
21 |
|
|
22 |
IF v_docid IS NOT NULL THEN |
|
23 |
-- current versions |
|
24 |
DELETE FROM xml_queryresult WHERE docid = v_docid; |
|
25 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
26 |
RAISE NOTICE 'Deleted % rows from xml_queryresult', deleted_count; |
|
27 |
|
|
28 |
DELETE FROM xml_path_index WHERE docid = v_docid; |
|
29 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
30 |
RAISE NOTICE 'Deleted % rows from xml_path_index', deleted_count; |
|
31 |
|
|
32 |
DELETE FROM xml_index WHERE docid = v_docid; |
|
33 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
34 |
RAISE NOTICE 'Deleted % rows from xml_index', deleted_count; |
|
35 |
|
|
36 |
DELETE FROM xml_documents WHERE docid = v_docid AND rev = v_rev; |
|
37 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
38 |
RAISE NOTICE 'Deleted % rows from xml_documents', deleted_count; |
|
39 |
|
|
40 |
DELETE FROM xml_nodes WHERE docid = v_docid; |
|
41 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
42 |
RAISE NOTICE 'Deleted % rows from xml_nodes', deleted_count; |
|
43 |
|
|
44 |
-- revisions |
|
45 |
DELETE FROM xml_revisions WHERE docid = v_docid AND rev = v_rev; |
|
46 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
47 |
RAISE NOTICE 'Deleted % rows from xml_revisions', deleted_count; |
|
48 |
|
|
49 |
DELETE FROM xml_nodes_revisions WHERE docid = v_docid; |
|
50 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
51 |
RAISE NOTICE 'Deleted % rows from xml_nodes_revisions', deleted_count; |
|
52 |
|
|
53 |
-- event logs |
|
54 |
DELETE FROM access_log WHERE docid = v_docid||'.'||v_rev; |
|
55 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
56 |
RAISE NOTICE 'Deleted % rows from access_log', deleted_count; |
|
57 |
|
|
58 |
-- reminder to delete filesystem content |
|
59 |
IF v_doctype = 'BIN' THEN |
|
60 |
RAISE NOTICE 'Remember to delete DATA file from filesystem docid: %.%', v_docid, v_rev; |
|
61 |
ELSE |
|
62 |
RAISE NOTICE 'Remember to delete METADATA file from filesystem docid: %.%', v_docid, v_rev; |
|
63 |
END IF; |
|
64 |
END IF; |
|
65 |
|
|
66 |
|
|
67 |
DELETE FROM systemMetadataReplicationPolicy WHERE guid = pid; |
|
68 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
69 |
RAISE NOTICE 'Deleted % rows from systemMetadataReplicationPolicy', deleted_count; |
|
70 |
|
|
71 |
DELETE FROM systemMetadataReplicationStatus WHERE guid = pid; |
|
72 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
73 |
RAISE NOTICE 'Deleted % rows from systemMetadataReplicationStatus', deleted_count; |
|
74 |
|
|
75 |
DELETE FROM systemMetadata WHERE guid = pid; |
|
76 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
77 |
RAISE NOTICE 'Deleted % rows from systemMetadata', deleted_count; |
|
78 |
|
|
79 |
DELETE FROM xml_access WHERE guid = pid; |
|
80 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
81 |
RAISE NOTICE 'Deleted % rows from xml_access', deleted_count; |
|
82 |
|
|
83 |
DELETE FROM identifier WHERE guid = pid; |
|
84 |
GET DIAGNOSTICS deleted_count = ROW_COUNT; |
|
85 |
RAISE NOTICE 'Deleted % rows from identifier', deleted_count; |
|
86 |
|
|
87 |
END; |
|
88 |
$$ |
|
89 |
LANGUAGE plpgsql; |
|
90 |
--BEGIN; select delete_all('bowles.55.4'); ROLLBACK; |
|
91 |
|
|
92 |
/** |
|
93 |
* This part of the script collects PIDS to be deleted |
|
94 |
* and performs the deletion on that set of pids. |
|
95 |
* Currently we are targeting all ORNLDAAC objects. |
|
96 |
* Update this section as needed. |
|
97 |
*/ |
|
98 |
-- Save the set of PIDs we are deleting |
|
99 |
CREATE TABLE pids_to_delete AS |
|
100 |
SELECT *, text(null) as docid, null::integer as rev |
|
101 |
FROM systemMetadata |
|
102 |
WHERE origin_member_node like 'urn:node:ORNLDAAC'; |
|
103 |
|
|
104 |
-- update with docid/rev if we have them |
|
105 |
UPDATE pids_to_delete ptd |
|
106 |
SET docid = id.docid, rev = id.rev |
|
107 |
FROM identifier id |
|
108 |
WHERE ptd.guid = id.guid; |
|
109 |
|
|
110 |
-- Do the delete |
|
111 |
BEGIN; |
|
112 |
SELECT delete_all(guid) FROM pids_to_delete; |
|
113 |
--ROLLBACK; |
|
114 |
COMMIT; |
|
115 |
-- Clean up |
|
116 |
DROP TABLE pids_to_delete; |
|
0 | 117 |
Also available in: Unified diff
function/procedure for removing all content related to a PID from the DB.
https://redmine.dataone.org/issues/3037