From a55a3d9442108fe95866fb8bc5a29bc962dd2809 Mon Sep 17 00:00:00 2001
From: Leo Gordon <lg4@ebi.ac.uk>
Date: Wed, 4 Dec 2013 11:26:09 +0000
Subject: [PATCH] schema_change: switched some foreign keys to ON DELETE
 CASCADE (thanks, Harpreet!)

---
 scripts/hoover_pipeline.pl |  6 +----
 sql/foreign_keys.sql       | 22 +++++++++----------
 sql/patch_2013-12-03.mysql | 45 ++++++++++++++++++++++++++++++++++++++
 sql/patch_2013-12-03.pgsql | 45 ++++++++++++++++++++++++++++++++++++++
 4 files changed, 102 insertions(+), 16 deletions(-)
 create mode 100644 sql/patch_2013-12-03.mysql
 create mode 100644 sql/patch_2013-12-03.pgsql

diff --git a/scripts/hoover_pipeline.pl b/scripts/hoover_pipeline.pl
index 5b690cbfb..2ad9f0be9 100755
--- a/scripts/hoover_pipeline.pl
+++ b/scripts/hoover_pipeline.pl
@@ -62,16 +62,12 @@ sub main {
     }
 
     my $sql = qq{
-        DELETE m,f,j
-          FROM job j
-     LEFT JOIN job_file f ON(f.job_id=j.job_id)
-     LEFT JOIN log_message m ON(m.job_id=j.job_id)
+    DELETE j FROM job j
      WHERE j.status='DONE'
        AND j.completed < $threshold_datetime_expression
     };
 
     my $dbc = $hive_dba->dbc();
-    $dbc->do( "SET FOREIGN_KEY_CHECKS=0" );
     $dbc->do( $sql );
 }
 
diff --git a/sql/foreign_keys.sql b/sql/foreign_keys.sql
index d06f723f0..8a019bdc4 100644
--- a/sql/foreign_keys.sql
+++ b/sql/foreign_keys.sql
@@ -12,19 +12,19 @@ ALTER TABLE job                     ADD FOREIGN KEY (analysis_id)
 ALTER TABLE analysis_stats          ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
 ALTER TABLE analysis_stats_monitor  ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
 
-ALTER TABLE job                     ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id);
-ALTER TABLE log_message             ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id);
-ALTER TABLE job_file                ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id);
-
-ALTER TABLE job                     ADD FOREIGN KEY (prev_job_id)               REFERENCES job(job_id);
-ALTER TABLE job                     ADD FOREIGN KEY (semaphored_job_id)         REFERENCES job(job_id);
-ALTER TABLE log_message             ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id);
-ALTER TABLE job_file                ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id);
-ALTER TABLE accu                    ADD FOREIGN KEY (sending_job_id)            REFERENCES job(job_id);
-ALTER TABLE accu                    ADD FOREIGN KEY (receiving_job_id)          REFERENCES job(job_id);
+ALTER TABLE dataflow_rule           ADD FOREIGN KEY (funnel_dataflow_rule_id)   REFERENCES dataflow_rule(dataflow_rule_id);
 
 ALTER TABLE resource_description    ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
 ALTER TABLE analysis_base           ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
 ALTER TABLE worker                  ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
 
-ALTER TABLE dataflow_rule           ADD FOREIGN KEY (funnel_dataflow_rule_id)   REFERENCES dataflow_rule(dataflow_rule_id);
+ALTER TABLE job                     ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+ALTER TABLE log_message             ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+ALTER TABLE job_file                ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+
+ALTER TABLE job                     ADD FOREIGN KEY (prev_job_id)               REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE job                     ADD FOREIGN KEY (semaphored_job_id)         REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE log_message             ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE job_file                ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE accu                    ADD FOREIGN KEY (sending_job_id)            REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE accu                    ADD FOREIGN KEY (receiving_job_id)          REFERENCES job(job_id)                          ON DELETE CASCADE;
diff --git a/sql/patch_2013-12-03.mysql b/sql/patch_2013-12-03.mysql
new file mode 100644
index 000000000..cc9ab7b16
--- /dev/null
+++ b/sql/patch_2013-12-03.mysql
@@ -0,0 +1,45 @@
+
+-- drop all foreign keys and re-create some of them with "ON DELETE CASCADE" rule:
+
+ALTER TABLE accu                    DROP FOREIGN KEY accu_ibfk_1, DROP FOREIGN KEY accu_ibfk_2;
+ALTER TABLE analysis_base           DROP FOREIGN KEY analysis_base_ibfk_1;
+ALTER TABLE analysis_ctrl_rule      DROP FOREIGN KEY analysis_ctrl_rule_ibfk_1;
+ALTER TABLE analysis_stats          DROP FOREIGN KEY analysis_stats_ibfk_1;
+ALTER TABLE analysis_stats_monitor  DROP FOREIGN KEY analysis_stats_monitor_ibfk_1;
+ALTER TABLE dataflow_rule           DROP FOREIGN KEY dataflow_rule_ibfk_1, DROP FOREIGN KEY dataflow_rule_ibfk_2;
+ALTER TABLE job                     DROP FOREIGN KEY job_ibfk_1, DROP FOREIGN KEY job_ibfk_2, DROP FOREIGN KEY job_ibfk_3, DROP FOREIGN KEY job_ibfk_4;
+ALTER TABLE job_file                DROP FOREIGN KEY job_file_ibfk_1, DROP FOREIGN KEY job_file_ibfk_2;
+ALTER TABLE log_message             DROP FOREIGN KEY log_message_ibfk_1, DROP FOREIGN KEY log_message_ibfk_2;
+ALTER TABLE resource_description    DROP FOREIGN KEY resource_description_ibfk_1;
+ALTER TABLE worker                  DROP FOREIGN KEY worker_ibfk_1, DROP FOREIGN KEY worker_ibfk_2;
+
+
+-- now just replay foreign_keys.sql :
+
+ALTER TABLE worker                  ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+ALTER TABLE dataflow_rule           ADD FOREIGN KEY (from_analysis_id)          REFERENCES analysis_base(analysis_id);
+ALTER TABLE analysis_ctrl_rule      ADD FOREIGN KEY (ctrled_analysis_id)        REFERENCES analysis_base(analysis_id);
+ALTER TABLE job                     ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+ALTER TABLE analysis_stats          ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+ALTER TABLE analysis_stats_monitor  ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+
+ALTER TABLE dataflow_rule           ADD FOREIGN KEY (funnel_dataflow_rule_id)   REFERENCES dataflow_rule(dataflow_rule_id);
+
+ALTER TABLE resource_description    ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
+ALTER TABLE analysis_base           ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
+ALTER TABLE worker                  ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
+
+ALTER TABLE job                     ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+ALTER TABLE log_message             ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+ALTER TABLE job_file                ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+
+ALTER TABLE job                     ADD FOREIGN KEY (prev_job_id)               REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE job                     ADD FOREIGN KEY (semaphored_job_id)         REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE log_message             ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE job_file                ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE accu                    ADD FOREIGN KEY (sending_job_id)            REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE accu                    ADD FOREIGN KEY (receiving_job_id)          REFERENCES job(job_id)                          ON DELETE CASCADE;
+
+    -- UPDATE hive_sql_schema_version
+UPDATE hive_meta SET meta_value=56 WHERE meta_key='hive_sql_schema_version' AND meta_value='55';
+
diff --git a/sql/patch_2013-12-03.pgsql b/sql/patch_2013-12-03.pgsql
new file mode 100644
index 000000000..477cb61a7
--- /dev/null
+++ b/sql/patch_2013-12-03.pgsql
@@ -0,0 +1,45 @@
+
+-- drop all foreign keys and re-create some of them with "ON DELETE CASCADE" rule:
+
+ALTER TABLE accu                    DROP CONSTRAINT accu_receiving_job_id_fkey, DROP CONSTRAINT accu_sending_job_id_fkey;
+ALTER TABLE analysis_base           DROP CONSTRAINT analysis_base_resource_class_id_fkey;
+ALTER TABLE analysis_ctrl_rule      DROP CONSTRAINT analysis_ctrl_rule_ctrled_analysis_id_fkey;
+ALTER TABLE analysis_stats          DROP CONSTRAINT analysis_stats_analysis_id_fkey;
+ALTER TABLE analysis_stats_monitor  DROP CONSTRAINT analysis_stats_monitor_analysis_id_fkey;
+ALTER TABLE dataflow_rule           DROP CONSTRAINT dataflow_rule_from_analysis_id_fkey, DROP CONSTRAINT dataflow_rule_funnel_dataflow_rule_id_fkey;
+ALTER TABLE job                     DROP CONSTRAINT job_analysis_id_fkey, DROP CONSTRAINT job_prev_job_id_fkey, DROP CONSTRAINT job_semaphored_job_id_fkey, DROP CONSTRAINT job_worker_id_fkey;
+ALTER TABLE job_file                DROP CONSTRAINT job_file_job_id_fkey, DROP CONSTRAINT job_file_worker_id_fkey;
+ALTER TABLE log_message             DROP CONSTRAINT log_message_job_id_fkey, DROP CONSTRAINT log_message_worker_id_fkey;
+ALTER TABLE resource_description    DROP CONSTRAINT resource_description_resource_class_id_fkey;
+ALTER TABLE worker                  DROP CONSTRAINT worker_analysis_id_fkey, DROP CONSTRAINT worker_resource_class_id_fkey;
+
+
+-- now just replay foreign_keys.sql :
+
+ALTER TABLE worker                  ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+ALTER TABLE dataflow_rule           ADD FOREIGN KEY (from_analysis_id)          REFERENCES analysis_base(analysis_id);
+ALTER TABLE analysis_ctrl_rule      ADD FOREIGN KEY (ctrled_analysis_id)        REFERENCES analysis_base(analysis_id);
+ALTER TABLE job                     ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+ALTER TABLE analysis_stats          ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+ALTER TABLE analysis_stats_monitor  ADD FOREIGN KEY (analysis_id)               REFERENCES analysis_base(analysis_id);
+
+ALTER TABLE dataflow_rule           ADD FOREIGN KEY (funnel_dataflow_rule_id)   REFERENCES dataflow_rule(dataflow_rule_id);
+
+ALTER TABLE resource_description    ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
+ALTER TABLE analysis_base           ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
+ALTER TABLE worker                  ADD FOREIGN KEY (resource_class_id)         REFERENCES resource_class(resource_class_id);
+
+ALTER TABLE job                     ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+ALTER TABLE log_message             ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+ALTER TABLE job_file                ADD FOREIGN KEY (worker_id)                 REFERENCES worker(worker_id)                    ON DELETE CASCADE;
+
+ALTER TABLE job                     ADD FOREIGN KEY (prev_job_id)               REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE job                     ADD FOREIGN KEY (semaphored_job_id)         REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE log_message             ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE job_file                ADD FOREIGN KEY (job_id)                    REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE accu                    ADD FOREIGN KEY (sending_job_id)            REFERENCES job(job_id)                          ON DELETE CASCADE;
+ALTER TABLE accu                    ADD FOREIGN KEY (receiving_job_id)          REFERENCES job(job_id)                          ON DELETE CASCADE;
+
+    -- UPDATE hive_sql_schema_version
+UPDATE hive_meta SET meta_value=56 WHERE meta_key='hive_sql_schema_version' AND meta_value='55';
+
-- 
GitLab