1
|
-- Restore original table names
|
2
|
ALTER TABLE "PlotMetadata" RENAME TO "plotMetadata";
|
3
|
ALTER TABLE "PlotObservations" RENAME TO "plotObservations";
|
4
|
|
5
|
-- Delete rows that do not satisfy foreign key constraints
|
6
|
-- these must happen in order starting with the outermost table
|
7
|
DELETE FROM "plotObservations" WHERE "PlotID" IN (
|
8
|
SELECT "plotObservations"."PlotID"
|
9
|
FROM "plotObservations"
|
10
|
LEFT JOIN "plotMetadata" ON "plotMetadata"."PlotID" = "plotObservations"."PlotID"
|
11
|
WHERE "plotMetadata"."PlotID" IS NULL
|
12
|
);
|
13
|
DELETE FROM stems WHERE "plotobs_id" IN (
|
14
|
SELECT stems."plotobs_id"
|
15
|
FROM stems
|
16
|
LEFT JOIN "plotObservations" ON "plotObservations"."PlotObsID" = stems."plotobs_id"
|
17
|
WHERE "plotObservations"."PlotObsID" IS NULL
|
18
|
);
|
19
|
|
20
|
-- Enable cascading deletes
|
21
|
|
22
|
CREATE INDEX ON "plotMetadata" (project_id);
|
23
|
ALTER TABLE "plotMetadata" ADD FOREIGN KEY (project_id) REFERENCES projects(project_id) ON UPDATE CASCADE ON DELETE CASCADE;
|
24
|
|
25
|
CREATE INDEX ON "plotObservations" ("PlotID");
|
26
|
ALTER TABLE "plotObservations" ADD FOREIGN KEY ("PlotID") REFERENCES "plotMetadata"("PlotID") ON UPDATE CASCADE ON DELETE CASCADE;
|
27
|
|
28
|
CREATE INDEX ON stems ("plotobs_id");
|
29
|
ALTER TABLE stems ADD FOREIGN KEY ("plotobs_id") REFERENCES "plotObservations"("PlotObsID") ON UPDATE CASCADE ON DELETE CASCADE;
|
30
|
|
31
|
-- Remove private data that should not be publicly visible
|
32
|
/*
|
33
|
"select * from lookup_plot_security_levels;
|
34
|
+-------+---------------------------+
|
35
|
| level | description |
|
36
|
+-------+---------------------------+
|
37
|
| 1 | No Access |
|
38
|
| 2 | Can view plot metadata |
|
39
|
| 3 | Can download plot details |
|
40
|
| 4 | Can assign access to plot |
|
41
|
+-------+---------------------------+
|
42
|
" (http://vegpath.org/fs/inputs/SALVIAS/_src/salvias_data_access_controls.txt)
|
43
|
*/
|
44
|
DELETE FROM "plotMetadata" WHERE "AccessCode" < 3;
|
45
|
|
46
|
-- Ensure globally unique column names when tables are joined
|
47
|
ALTER TABLE "lookup_MethodCode" RENAME "Description" TO "lookup_MethodCode_Description";
|