diff --git a/scripts/general/tables-columns-exists-proc.sql b/scripts/general/tables-columns-exists-proc.sql index 8dfca8f..6537609 100644 --- a/scripts/general/tables-columns-exists-proc.sql +++ b/scripts/general/tables-columns-exists-proc.sql @@ -31,7 +31,9 @@ END; CREATE OR REPLACE PROCEDURE `clinvar_ingest.validate_last_release`( table_name STRING, - previous_release_date DATE + previous_release_date DATE, + OUT is_valid BOOL, + OUT validation_message STRING ) BEGIN DECLARE last_processed_release_date DATE; @@ -43,16 +45,15 @@ BEGIN """, table_name) INTO last_processed_release_date; -- validate that the max end_release_date is the previous release date otherwise throw an error - IF last_processed_release_date != previous_release_date THEN - BEGIN - DECLARE error_message STRING; - SET error_message = FORMAT(""" - The last processed release date (%t) in clinvar_genes - is not equal to the expected previous release date (%t). - Processing of clinvar_genes will not continue. - """, last_processed_release_date, previous_release_date); - RAISE USING message = error_message; - END; + SET is_valid = (last_processed_release_date != previous_release_date); + IF NOT is_valid THEN + SET validation_message = FORMAT(""" + %s was last processed for release date %t but the expected date is %t. + """, table_name, last_processed_release_date, previous_release_date); + ELSE + SET validation_message = FORMAT(""" + %s was last processed for release date %t as expected. + """, table_name, last_processed_release_date, previous_release_date); END IF; END; diff --git a/scripts/temporal-data-collection/01-clinvar-genes-proc.sql b/scripts/temporal-data-collection/01-clinvar-genes-proc.sql index a98d6a7..32b9a60 100644 --- a/scripts/temporal-data-collection/01-clinvar-genes-proc.sql +++ b/scripts/temporal-data-collection/01-clinvar-genes-proc.sql @@ -1,12 +1,20 @@ CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_genes`( schema_name STRING, release_date DATE, - previous_release_date DATE + previous_release_date DATE, + OUT result_message STRING ) -BEGIN - -- validate the last release date for the 2 tables processed in this procedure - CALL `clinvar_ingest.validate_last_release`('clinvar_genes',previous_release_date); - CALL `clinvar_ingest.validate_last_release`('clinvar_single_gene_variations',previous_release_date); +BEGIN + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; + + -- validate the last release date for clinvar_genes + CALL `clinvar_ingest.validate_last_release`('clinvar_genes', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_genes processing. " + validation_message; + RETURN; + END IF; -- deleted genes (where it exists in clinvar_genes (for deleted_release_date is null), but doesn't exist in current data set ) EXECUTE IMMEDIATE FORMAT(""" @@ -27,25 +35,6 @@ BEGIN ) """, release_date, schema_name); - -- deleted single gene vars (where it exists in clinvar_single_gene_variations(for deleted_release_date is null), but doesn't exist in current data set ) - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_single_gene_variations` csgv - SET - deleted_release_date = %T, - deleted_count = deleted_count + 1 - WHERE - csgv.deleted_release_date is NULL - AND - NOT EXISTS - ( - SELECT - sgv.variation_id - FROM `%s.single_gene_variation` sgv - WHERE - sgv.variation_id = csgv.variation_id - ) - """, release_date, schema_name); - -- updated genes EXECUTE IMMEDIATE FORMAT(""" UPDATE `clinvar_ingest.clinvar_genes` cg @@ -59,22 +48,6 @@ BEGIN g.id = cg.id """, schema_name); - -- updated single gene variations - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_single_gene_variations` csgv - SET - gene_id = sgv.gene_id, - mane_select = sgv.mane_select, - somatic = sgv.somatic, - relationship_type = sgv.relationship_type, - source = sgv.source, - end_release_date = sgv.release_date, - deleted_release_date = NULL - FROM `%s.single_gene_variation` sgv - WHERE - sgv.variation_id = csgv.variation_id - """, schema_name); - -- new genes EXECUTE IMMEDIATE FORMAT(""" INSERT `clinvar_ingest.clinvar_genes` ( @@ -102,222 +75,6 @@ BEGIN ) """, schema_name); - -- new single gene variations - EXECUTE IMMEDIATE FORMAT(""" - INSERT `clinvar_ingest.clinvar_single_gene_variations` ( - gene_id, - variation_id, - relationship_type, - source, - mane_select, - somatic, - start_release_date, - end_release_date - ) - SELECT - sgv.gene_id, - sgv.variation_id, - sgv.relationship_type, - sgv.source, - sgv.mane_select, - sgv.somatic, - sgv.release_date as start_release_date, - sgv.release_date as end_release_date - FROM `%s.single_gene_variation` sgv - WHERE - NOT EXISTS - ( - SELECT - csgv.variation_id - FROM `clinvar_ingest.clinvar_single_gene_variations` csgv - WHERE - sgv.variation_id = csgv.variation_id - ) - """, schema_name); - -END; - - --- NOTE: we don't need clinvar_gene_assoications captured across all datasets --- for now we comment out the clinvar_gene_associations create, update and insert statements --- ONLY clinvar_genes and clinvar_single_gene_variations should be built until there is a need. - - --- CREATE OR REPLACE TABLE `clinvar_ingest.clinvar_gene_associations` --- ( --- variation_id STRING NOT NULL, --- gene_id STRING NOT NULL, --- relationship_type STRING, --- source STRING, --- start_release_date DATE, --- end_release_date DATE, --- deleted_release_date DATE, --- deleted_count INT DEFAULT 0 --- ); - --- -- FIX gene_association duplicate row issues by --- -- removing dupes and saving as table --- DROP VIEW `clinvar_2022_07_24_v1_6_46.gene_association`; --- CREATE OR REPLACE TABLE `clinvar_2022_07_24_v1_6_46.gene_association` --- AS --- SELECT --- x.datarepo_row_id, --- x.source, --- x.variation_id, --- x.release_date, --- x.relationship_type, --- x.content, --- x.gene_id --- FROM ( --- SELECT --- *, --- ROW_NUMBER() --- OVER (PARTITION BY gene_id, variation_id) --- row_number --- FROM `datarepo-550c0177.clinvar_2022_07_24_v1_6_46.gene_association` --- ) x --- WHERE x.row_number = 1 --- ; --- CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_genes_proc`(start_with DATE) --- BEGIN - --- FOR rec IN (select s.schema_name, s.release_date, s.next_release_date FROM clinvar_ingest.schemas_on_or_after(start_with) as s) --- DO - --- -- -- deleted genes (where it exists in clinvar_genes (for deleted_release_date is null), but doesn't exist in current data set ) --- -- EXECUTE IMMEDIATE FORMAT(""" --- -- UPDATE `clinvar_ingest.clinvar_genes` cg --- -- SET deleted_release_date = %T, --- -- deleted_count = deleted_count + 1 --- -- WHERE cg.deleted_release_date is NULL --- -- AND NOT EXISTS ( --- -- SELECT g.id FROM `%s.gene` g --- -- WHERE g.release_date = %T AND g.id = cg.id --- -- ) --- -- """, rec.release_date, rec.schema_name, rec.release_date); - --- -- -- deleted gene assocs (where it exists in clinvar_gene_associations (for deleted_release_date is null), but doesn't exist in current data set ) --- -- EXECUTE IMMEDIATE FORMAT(""" --- -- UPDATE `clinvar_ingest.clinvar_gene_associations` cga --- -- SET deleted_release_date = %T, --- -- deleted_count = deleted_count + 1 --- -- WHERE cga.deleted_release_date is NULL --- -- AND NOT EXISTS ( --- -- SELECT ga.gene_id, ga.variation_id FROM `%s.gene_association` ga --- -- WHERE ga.release_date = %T AND ga.variation_id = cga.variation_id AND ga.gene_id = cga.gene_id --- -- ) --- -- """, rec.release_date, rec.schema_name, rec.release_date); - --- -- deleted single gene vars (where it exists in clinvar_single_gene_variations(for deleted_release_date is null), but doesn't exist in current data set ) --- EXECUTE IMMEDIATE FORMAT(""" --- UPDATE `clinvar_ingest.clinvar_single_gene_variations` csgv --- SET deleted_release_date = %T, --- deleted_count = deleted_count + 1 --- WHERE csgv.deleted_release_date is NULL --- AND NOT EXISTS ( --- SELECT sgv.variation_id FROM `%s.single_gene_variation` sgv --- WHERE sgv.release_date = %T AND sgv.variation_id = csgv.variation_id --- ) --- """, rec.release_date, rec.schema_name, rec.release_date); - --- -- -- updated genes --- -- EXECUTE IMMEDIATE FORMAT(""" --- -- UPDATE `clinvar_ingest.clinvar_genes` cg --- -- SET --- -- hgnc_id = g.hgnc_id, --- -- symbol = g.symbol, --- -- end_release_date = g.release_date, --- -- deleted_release_date = NULL --- -- FROM `%s.gene` g --- -- WHERE g.release_date = %T AND g.id = cg.id --- -- """, rec.schema_name, rec.release_date); - --- -- -- updated gene associations --- -- EXECUTE IMMEDIATE FORMAT(""" --- -- UPDATE `clinvar_ingest.clinvar_gene_associations` cga --- -- SET --- -- relationship_type = ga.relationship_type, --- -- source = ga.source, --- -- end_release_date = ga.release_date, --- -- deleted_release_date = NULL --- -- FROM `%s.gene_association` ga --- -- WHERE ga.release_date = %T AND ga.variation_id = cga.variation_id AND ga.gene_id = cga.gene_id --- -- """, rec.schema_name, rec.release_date); - --- -- updated single gene variations --- EXECUTE IMMEDIATE FORMAT(""" --- UPDATE `clinvar_ingest.clinvar_single_gene_variations` csgv --- SET --- gene_id = sgv.gene_id, --- mane_select = sgv.mane_select, --- somatic = sgv.somatic, --- relationship_type = sgv.relationship_type, --- source = sgv.source, --- end_release_date = sgv.release_date, --- deleted_release_date = NULL --- FROM `%s.single_gene_variation` sgv --- WHERE sgv.release_date = %T AND sgv.variation_id = csgv.variation_id --- """, rec.schema_name, rec.release_date); - --- -- -- new genes --- -- EXECUTE IMMEDIATE FORMAT(""" --- -- INSERT `clinvar_ingest.clinvar_genes` --- -- (id, symbol, hgnc_id, start_release_date, end_release_date) --- -- SELECT --- -- g.id, --- -- g.symbol, --- -- g.hgnc_id, --- -- g.release_date as start_release_date, --- -- g.release_date as end_release_date --- -- FROM `%s.gene` g --- -- WHERE g.release_date = %T --- -- AND NOT EXISTS ( --- -- SELECT cg.id FROM `clinvar_ingest.clinvar_genes` cg --- -- WHERE cg.id = g.id --- -- ) --- -- """, rec.schema_name, rec.release_date); - --- -- -- new gene associations --- -- EXECUTE IMMEDIATE FORMAT(""" --- -- INSERT `clinvar_ingest.clinvar_gene_associations` --- -- (gene_id, variation_id, relationship_type, source, start_release_date, end_release_date) --- -- SELECT --- -- ga.gene_id, --- -- ga.variation_id, --- -- ga.relationship_type, --- -- ga.source, --- -- ga.release_date as start_release_date, --- -- ga.release_date as end_release_date --- -- FROM `%s.gene_association` ga --- -- WHERE ga.release_date = %T --- -- AND NOT EXISTS ( --- -- SELECT cga.gene_id, cga.variation_id FROM `clinvar_ingest.clinvar_gene_associations` cga --- -- WHERE ga.variation_id = cga.variation_id AND ga.gene_id = cga.gene_id --- -- ) --- -- """, rec.schema_name, rec.release_date); - --- -- new single gene variations --- EXECUTE IMMEDIATE FORMAT(""" --- INSERT `clinvar_ingest.clinvar_single_gene_variations` --- (gene_id, variation_id, relationship_type, source, mane_select, somatic, start_release_date, end_release_date) --- SELECT --- sgv.gene_id, --- sgv.variation_id, --- sgv.relationship_type, --- sgv.source, --- sgv.mane_select, --- sgv.somatic, --- sgv.release_date as start_release_date, --- sgv.release_date as end_release_date --- FROM `%s.single_gene_variation` sgv --- WHERE sgv.release_date = %T --- AND NOT EXISTS ( --- SELECT csgv.variation_id FROM `clinvar_ingest.clinvar_single_gene_variations` csgv --- WHERE sgv.variation_id = csgv.variation_id --- ) --- """, rec.schema_name, rec.release_date); - --- END FOR; - --- END; + SET result_message = "clinvar_genes processing completed successfully."; +END; \ No newline at end of file diff --git a/scripts/temporal-data-collection/02-clinvar-single-gene-variations-proc.sql b/scripts/temporal-data-collection/02-clinvar-single-gene-variations-proc.sql new file mode 100644 index 0000000..f214e11 --- /dev/null +++ b/scripts/temporal-data-collection/02-clinvar-single-gene-variations-proc.sql @@ -0,0 +1,89 @@ +CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_single_gene_variations`( + schema_name STRING, + release_date DATE, + previous_release_date DATE, + OUT result_message STRING +) +BEGIN + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; + + -- validate the last release date for clinvar_single_gene_variations + CALL `clinvar_ingest.validate_last_release`('clinvar_single_gene_variations', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_single_gene_variations processing. " + validation_message; + RETURN; + END IF; + + -- deleted single gene vars (where it exists in clinvar_single_gene_variations(for deleted_release_date is null), but doesn't exist in current data set ) + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_single_gene_variations` csgv + SET + deleted_release_date = %T, + deleted_count = deleted_count + 1 + WHERE + csgv.deleted_release_date is NULL + AND + NOT EXISTS + ( + SELECT + sgv.variation_id + FROM `%s.single_gene_variation` sgv + WHERE + sgv.variation_id = csgv.variation_id + ) + """, release_date, schema_name); + + -- updated single gene variations + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_single_gene_variations` csgv + SET + gene_id = sgv.gene_id, + mane_select = sgv.mane_select, + somatic = sgv.somatic, + relationship_type = sgv.relationship_type, + source = sgv.source, + end_release_date = sgv.release_date, + deleted_release_date = NULL + FROM `%s.single_gene_variation` sgv + WHERE + sgv.variation_id = csgv.variation_id + """, schema_name); + + -- new single gene variations + EXECUTE IMMEDIATE FORMAT(""" + INSERT `clinvar_ingest.clinvar_single_gene_variations` ( + gene_id, + variation_id, + relationship_type, + source, + mane_select, + somatic, + start_release_date, + end_release_date + ) + SELECT + sgv.gene_id, + sgv.variation_id, + sgv.relationship_type, + sgv.source, + sgv.mane_select, + sgv.somatic, + sgv.release_date as start_release_date, + sgv.release_date as end_release_date + FROM `%s.single_gene_variation` sgv + WHERE + NOT EXISTS + ( + SELECT + csgv.variation_id + FROM `clinvar_ingest.clinvar_single_gene_variations` csgv + WHERE + sgv.variation_id = csgv.variation_id + ) + """, schema_name); + + SET result_message = 'clinvar_single_gene_variations processed successfully'; + +END; \ No newline at end of file diff --git a/scripts/temporal-data-collection/02-clinvar-submitters-proc.sql b/scripts/temporal-data-collection/03-clinvar-submitters-proc.sql similarity index 96% rename from scripts/temporal-data-collection/02-clinvar-submitters-proc.sql rename to scripts/temporal-data-collection/03-clinvar-submitters-proc.sql index fe3dc61..55a767f 100644 --- a/scripts/temporal-data-collection/02-clinvar-submitters-proc.sql +++ b/scripts/temporal-data-collection/03-clinvar-submitters-proc.sql @@ -6,12 +6,21 @@ CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_submitters`( schema_name STRING, release_date DATE, - previous_release_date DATE + previous_release_date DATE, + OUT validation_message STRING ) BEGIN - -- validate the last release date clinvar_submitters - CALL `clinvar_ingest.validate_last_release`('clinvar_submitters',previous_release_date); - + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE error_message STRING DEFAULT ''; + + -- validate the last release date for clinvar_submitters + CALL `clinvar_ingest.validate_last_release`('clinvar_submitters', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_submitters processing. " + validation_message; + RETURN; + END IF; + -- deleted submitters (where it exists in clinvar_submitters (for deleted_release_date is null), but doesn't exist in current data set ) EXECUTE IMMEDIATE FORMAT(""" UPDATE `clinvar_ingest.clinvar_submitters` cs @@ -83,8 +92,9 @@ BEGIN ) """, schema_name); -END; + SET result_message = "clinvar_submitters processed successfully"; +END; -- -- initialize submitter info by release based on clinical_assertion release info, diff --git a/scripts/temporal-data-collection/03-clinvar-variations-proc.sql b/scripts/temporal-data-collection/04-clinvar-variations-proc.sql similarity index 76% rename from scripts/temporal-data-collection/03-clinvar-variations-proc.sql rename to scripts/temporal-data-collection/04-clinvar-variations-proc.sql index aa85f60..16f8c94 100644 --- a/scripts/temporal-data-collection/03-clinvar-variations-proc.sql +++ b/scripts/temporal-data-collection/04-clinvar-variations-proc.sql @@ -2,11 +2,20 @@ CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_variations`( schema_name STRING, release_date DATE, - previous_release_date DATE + previous_release_date DATE, + OUT result_message STRING ) -BEGIN - -- validate the last release date clinvar_variations - CALL `clinvar_ingest.validate_last_release`('clinvar_variations',previous_release_date); +BEGIN + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; + + -- validate the last release date for clinvar_variations + CALL `clinvar_ingest.validate_last_release`('clinvar_variations', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_variations processing. " + validation_message; + RETURN; + END IF; -- deleted variations (where it exists in clinvar_variations (for deleted_release_date is null), but doesn't exist in current data set ) EXECUTE IMMEDIATE FORMAT(""" @@ -62,4 +71,6 @@ BEGIN ) """, schema_name); + SET result_message = "clinvar_variations processed successfully"; + END; diff --git a/scripts/temporal-data-collection/04-clinvar-vcvs-proc.sql b/scripts/temporal-data-collection/04-clinvar-vcvs-proc.sql deleted file mode 100644 index d0b2f5c..0000000 --- a/scripts/temporal-data-collection/04-clinvar-vcvs-proc.sql +++ /dev/null @@ -1,331 +0,0 @@ -CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_vcvs`( - schema_name STRING, - release_date DATE, - previous_release_date DATE -) -BEGIN - DECLARE project_id STRING; - - SET project_id = - ( - SELECT - catalog_name as paroject_id - FROM `INFORMATION_SCHEMA.SCHEMATA` - WHERE - schema_name = 'clinvar_ingest' - ); - - IF (project_id = 'clingen-stage') THEN - - -- validate the last release date clinvar_vcvs - CALL `clinvar_ingest.validate_last_release`('clinvar_vcvs',previous_release_date); - - -- deleted vcvs (where it exists in clinvar_vcvs (for deleted_release_date is null), but doesn't exist in current data set ) - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_vcvs` cvcv - SET - deleted_release_date = %T, - deleted_count = deleted_count + 1 - WHERE - cvcv.deleted_release_date is NULL - AND - NOT EXISTS ( - SELECT - vcv.id - FROM `%s.variation_archive` vcv - LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 - ON - cvs1.label = vcv.review_status - WHERE - vcv.variation_id = cvcv.variation_id - AND - vcv.id = cvcv.id - AND - vcv.version = cvcv.version - AND - cvs1.rank IS NOT DISTINCT FROM cvcv.rank - AND - vcv.interp_description IS NOT DISTINCT FROM cvcv.agg_classification - AND - vcv.interp_date_last_evaluated IS NOT DISTINCT FROM cvcv.last_evaluated - ) - """, release_date, schema_name); - - -- updated variations - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_vcvs` cvcv - SET - end_release_date = vcv.release_date, - deleted_release_date = NULL - FROM `%s.variation_archive` vcv - LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 - ON - cvs1.label = vcv.review_status - WHERE - vcv.variation_id = cvcv.variation_id - AND - vcv.id = cvcv.id - AND - vcv.version = cvcv.version - AND - cvs1.rank IS NOT DISTINCT FROM cvcv.rank - AND - vcv.interp_description IS NOT DISTINCT FROM cvcv.agg_classification - AND - vcv.interp_date_last_evaluated IS NOT DISTINCT FROM cvcv.last_evaluated - """, schema_name); - - -- new variation_archive - EXECUTE IMMEDIATE FORMAT(""" - INSERT INTO `clinvar_ingest.clinvar_vcvs` ( - variation_id, - id, - version, - rank, - last_evaluated, - agg_classification, - start_release_date, - end_release_date - ) - SELECT - vcv.variation_id, - vcv.id, - vcv.version, - cvs1.rank, - vcv.interp_date_last_evaluated as last_evaluated, - vcv.interp_description as agg_classification, - vcv.release_date as start_release_date, - vcv.release_date as end_release_date - FROM `%s.variation_archive` vcv - LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 - ON - cvs1.label = vcv.review_status - WHERE - NOT EXISTS ( - SELECT - cvcv.id - FROM `clinvar_ingest.clinvar_vcvs` cvcv - WHERE - vcv.variation_id = cvcv.variation_id - AND - vcv.id = cvcv.id - AND - vcv.version = cvcv.version - AND - cvs1.rank IS NOT DISTINCT FROM cvcv.rank - AND - vcv.interp_description IS NOT DISTINCT FROM cvcv.agg_classification - AND - vcv.interp_date_last_evaluated IS NOT DISTINCT FROM cvcv.last_evaluated - ) - """, schema_name); - - ELSE - - -- validate the last release date clinvar_vcvs - CALL `clinvar_ingest.validate_last_release`('clinvar_vcvs',previous_release_date); - CALL `clinvar_ingest.validate_last_release`('clinvar_vcv_classifications',previous_release_date); - - -- deleted vcvs (where it exists in clinvar_vcvs (for deleted_release_date is null), but doesn't exist in current data set ) - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_vcvs` cvcv - SET - deleted_release_date = %T, - deleted_count = deleted_count + 1 - WHERE - cvcv.deleted_release_date is NULL - AND - NOT EXISTS ( - SELECT - vcv.id - FROM `%s.variation_archive` vcv - WHERE - vcv.variation_id = cvcv.variation_id - AND - vcv.id = cvcv.id - AND - vcv.version = cvcv.version - ) - """, release_date, schema_name); - - -- updated variations - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_vcvs` cvcv - SET - end_release_date = vcv.release_date, - deleted_release_date = NULL - FROM `%s.variation_archive` vcv - WHERE - vcv.variation_id = cvcv.variation_id - AND - vcv.id = cvcv.id - AND - vcv.version = cvcv.version - """, schema_name); - - -- new variation_archive - EXECUTE IMMEDIATE FORMAT(""" - INSERT INTO `clinvar_ingest.clinvar_vcvs` ( - variation_id, - id, - version, - start_release_date, - end_release_date - ) - SELECT - vcv.variation_id, - vcv.id, - vcv.version, - vcv.release_date as start_release_date, - vcv.release_date as end_release_date - FROM `%s.variation_archive` vcv - WHERE - NOT EXISTS ( - SELECT - cvcv.id - FROM `clinvar_ingest.clinvar_vcvs` cvcv - WHERE - vcv.variation_id = cvcv.variation_id - AND - vcv.id = cvcv.id - AND - vcv.version = cvcv.version - ) - """, schema_name); - - -- deleted vcv_classifications (where it exists in clinvar_vcv_classifications (for deleted_release_date is null), but doesn't exist in current data set ) - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_vcv_classifications` cvcvc - SET - deleted_release_date = %T, - deleted_count = deleted_count + 1 - WHERE - cvcvc.deleted_release_date is NULL - AND - NOT EXISTS ( - SELECT - vcvc.vcv_id - FROM `%s.variation_archive_classification` vcvc - LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 - ON - cvs1.label = vcvc.review_status - WHERE - vcvc.vcv_id = cvcvc.vcv_id - AND - vcvc.statement_type IS NOT DISTINCT FROM cvcvc.statement_type - AND - cvs1.rank IS NOT DISTINCT FROM cvcvc.rank - AND - vcvc.interp_date_last_evaluated IS NOT DISTINCT FROM cvcvc.last_evaluated - AND - vcvc.interp_description IS NOT DISTINCT FROM cvcvc.agg_classification_description - AND - vcvc.num_submitters IS NOT DISTINCT FROM cvcvc.num_submitters - AND - vcvc.num_submissions IS NOT DISTINCT FROM cvcvc.num_submissions - AND - vcvc.most_recent_submission IS NOT DISTINCT FROM cvcvc.most_recent_submission - AND - vcvc.clinical_impact_assertion_type IS NOT DISTINCT FROM cvcvc.clinical_impact_assertion_type - AND - vcvc.clinical_impact_clinical_significance IS NOT DISTINCT FROM cvcvc.clinical_impact_clinical_significance - ) - """, release_date, schema_name); - - -- updated variations - EXECUTE IMMEDIATE FORMAT(""" - UPDATE `clinvar_ingest.clinvar_vcv_classifications` cvcvc - SET - end_release_date = %T, - deleted_release_date = NULL - FROM `%s.variation_archive_classification` vcvc - LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 - ON - cvs1.label = vcvc.review_status - WHERE - vcvc.vcv_id = cvcvc.vcv_id - AND - vcvc.statement_type IS NOT DISTINCT FROM cvcvc.statement_type - AND - cvs1.rank IS NOT DISTINCT FROM cvcvc.rank - AND - vcvc.interp_date_last_evaluated IS NOT DISTINCT FROM cvcvc.last_evaluated - AND - vcvc.interp_description IS NOT DISTINCT FROM cvcvc.agg_classification_description - AND - vcvc.num_submitters IS NOT DISTINCT FROM cvcvc.num_submitters - AND - vcvc.num_submissions IS NOT DISTINCT FROM cvcvc.num_submissions - AND - vcvc.most_recent_submission IS NOT DISTINCT FROM cvcvc.most_recent_submission - AND - vcvc.clinical_impact_assertion_type IS NOT DISTINCT FROM cvcvc.clinical_impact_assertion_type - AND - vcvc.clinical_impact_clinical_significance IS NOT DISTINCT FROM cvcvc.clinical_impact_clinical_significance - """, release_date, schema_name); - - -- new variation_archive_classification - EXECUTE IMMEDIATE FORMAT(""" - INSERT INTO `clinvar_ingest.clinvar_vcv_classifications` ( - vcv_id, - statement_type, - rank, - last_evaluated, - agg_classification_description, - num_submitters, - num_submissions, - most_recent_submission, - clinical_impact_assertion_type, - clinical_impact_clinical_significance, - start_release_date, - end_release_date - ) - SELECT - vcvc.vcv_id, - vcvc.statement_type, - cvs1.rank, - vcvc.interp_date_last_evaluated as last_evaluated, - vcvc.interp_description as agg_classification_description, - vcvc.num_submitters, - vcvc.num_submissions, - vcvc.most_recent_submission, - vcvc.clinical_impact_assertion_type, - vcvc.clinical_impact_clinical_significance, - %T as start_release_date, - %T as end_release_date - FROM `%s.variation_archive_classification` vcvc - -- dataset term check in dataset-preparation scripts should assure all statuses are present - -- just in case we should keep outer join to allow null 'rank' to be produced to assure no - -- records are skipped in the final result set. - LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 - ON - cvs1.label = vcvc.review_status - WHERE - NOT EXISTS ( - SELECT cvcvc.vcv_id - FROM `clinvar_ingest.clinvar_vcv_classifications` cvcvc - WHERE - vcvc.vcv_id = cvcvc.vcv_id AND - vcvc.statement_type IS NOT DISTINCT FROM cvcvc.statement_type - AND - cvs1.rank IS NOT DISTINCT FROM cvcvc.rank - AND - vcvc.interp_date_last_evaluated IS NOT DISTINCT FROM cvcvc.last_evaluated - AND - vcvc.interp_description IS NOT DISTINCT FROM cvcvc.agg_classification_description - AND - vcvc.num_submitters IS NOT DISTINCT FROM cvcvc.num_submitters - AND - vcvc.num_submissions IS NOT DISTINCT FROM cvcvc.num_submissions - AND - vcvc.most_recent_submission IS NOT DISTINCT FROM cvcvc.most_recent_submission - AND - vcvc.clinical_impact_assertion_type IS NOT DISTINCT FROM cvcvc.clinical_impact_assertion_type - AND - vcvc.clinical_impact_clinical_significance IS NOT DISTINCT FROM cvcvc.clinical_impact_clinical_significance - ) - """, release_date, release_date, schema_name); - - END IF; - -END; \ No newline at end of file diff --git a/scripts/temporal-data-collection/05-clinvar-vcvs-proc.sql b/scripts/temporal-data-collection/05-clinvar-vcvs-proc.sql new file mode 100644 index 0000000..3d2d643 --- /dev/null +++ b/scripts/temporal-data-collection/05-clinvar-vcvs-proc.sql @@ -0,0 +1,204 @@ +CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_vcvs`( + schema_name STRING, + release_date DATE, + previous_release_date DATE, + OUT result_message STRING +) +BEGIN + DECLARE project_id STRING; + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; + + SET project_id = + ( + SELECT + catalog_name as paroject_id + FROM `INFORMATION_SCHEMA.SCHEMATA` + WHERE + schema_name = 'clinvar_ingest' + ); + + -- validate the last release date for clinvar_vcvs + CALL `clinvar_ingest.validate_last_release`('clinvar_vcvs', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_vcvs processing. " + validation_message; + RETURN; + END IF; + + IF (project_id = 'clingen-stage') THEN + + -- deleted vcvs (where it exists in clinvar_vcvs (for deleted_release_date is null), but doesn't exist in current data set ) + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_vcvs` cvcv + SET + deleted_release_date = %T, + deleted_count = deleted_count + 1 + WHERE + cvcv.deleted_release_date is NULL + AND + NOT EXISTS ( + SELECT + vcv.id + FROM `%s.variation_archive` vcv + LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 + ON + cvs1.label = vcv.review_status + WHERE + vcv.variation_id = cvcv.variation_id + AND + vcv.id = cvcv.id + AND + vcv.version = cvcv.version + AND + cvs1.rank IS NOT DISTINCT FROM cvcv.rank + AND + vcv.interp_description IS NOT DISTINCT FROM cvcv.agg_classification + AND + vcv.interp_date_last_evaluated IS NOT DISTINCT FROM cvcv.last_evaluated + ) + """, release_date, schema_name); + + -- updated variations + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_vcvs` cvcv + SET + end_release_date = vcv.release_date, + deleted_release_date = NULL + FROM `%s.variation_archive` vcv + LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 + ON + cvs1.label = vcv.review_status + WHERE + vcv.variation_id = cvcv.variation_id + AND + vcv.id = cvcv.id + AND + vcv.version = cvcv.version + AND + cvs1.rank IS NOT DISTINCT FROM cvcv.rank + AND + vcv.interp_description IS NOT DISTINCT FROM cvcv.agg_classification + AND + vcv.interp_date_last_evaluated IS NOT DISTINCT FROM cvcv.last_evaluated + """, schema_name); + + -- new variation_archive + EXECUTE IMMEDIATE FORMAT(""" + INSERT INTO `clinvar_ingest.clinvar_vcvs` ( + variation_id, + id, + version, + rank, + last_evaluated, + agg_classification, + start_release_date, + end_release_date + ) + SELECT + vcv.variation_id, + vcv.id, + vcv.version, + cvs1.rank, + vcv.interp_date_last_evaluated as last_evaluated, + vcv.interp_description as agg_classification, + vcv.release_date as start_release_date, + vcv.release_date as end_release_date + FROM `%s.variation_archive` vcv + LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 + ON + cvs1.label = vcv.review_status + WHERE + NOT EXISTS ( + SELECT + cvcv.id + FROM `clinvar_ingest.clinvar_vcvs` cvcv + WHERE + vcv.variation_id = cvcv.variation_id + AND + vcv.id = cvcv.id + AND + vcv.version = cvcv.version + AND + cvs1.rank IS NOT DISTINCT FROM cvcv.rank + AND + vcv.interp_description IS NOT DISTINCT FROM cvcv.agg_classification + AND + vcv.interp_date_last_evaluated IS NOT DISTINCT FROM cvcv.last_evaluated + ) + """, schema_name); + + ELSE + + -- deleted vcvs (where it exists in clinvar_vcvs (for deleted_release_date is null), but doesn't exist in current data set ) + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_vcvs` cvcv + SET + deleted_release_date = %T, + deleted_count = deleted_count + 1 + WHERE + cvcv.deleted_release_date is NULL + AND + NOT EXISTS ( + SELECT + vcv.id + FROM `%s.variation_archive` vcv + WHERE + vcv.variation_id = cvcv.variation_id + AND + vcv.id = cvcv.id + AND + vcv.version = cvcv.version + ) + """, release_date, schema_name); + + -- updated variations + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_vcvs` cvcv + SET + end_release_date = vcv.release_date, + deleted_release_date = NULL + FROM `%s.variation_archive` vcv + WHERE + vcv.variation_id = cvcv.variation_id + AND + vcv.id = cvcv.id + AND + vcv.version = cvcv.version + """, schema_name); + + -- new variation_archive + EXECUTE IMMEDIATE FORMAT(""" + INSERT INTO `clinvar_ingest.clinvar_vcvs` ( + variation_id, + id, + version, + start_release_date, + end_release_date + ) + SELECT + vcv.variation_id, + vcv.id, + vcv.version, + vcv.release_date as start_release_date, + vcv.release_date as end_release_date + FROM `%s.variation_archive` vcv + WHERE + NOT EXISTS ( + SELECT + cvcv.id + FROM `clinvar_ingest.clinvar_vcvs` cvcv + WHERE + vcv.variation_id = cvcv.variation_id + AND + vcv.id = cvcv.id + AND + vcv.version = cvcv.version + ) + """, schema_name); + + END IF; + + SET result_message = 'clinvar_vcvs processed successfully.'; + +END; \ No newline at end of file diff --git a/scripts/temporal-data-collection/06-clinvar-vcv-classifications-proc.sql b/scripts/temporal-data-collection/06-clinvar-vcv-classifications-proc.sql new file mode 100644 index 0000000..90edfde --- /dev/null +++ b/scripts/temporal-data-collection/06-clinvar-vcv-classifications-proc.sql @@ -0,0 +1,169 @@ +CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_vcv_classifications`( + schema_name STRING, + release_date DATE, + previous_release_date DATE, + OUT result_message STRING +) +BEGIN + DECLARE project_id STRING; + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; + + SET project_id = + ( + SELECT + catalog_name as paroject_id + FROM `INFORMATION_SCHEMA.SCHEMATA` + WHERE + schema_name = 'clinvar_ingest' + ); + + -- skip clinvar_vcv_classifications processing for clingen-stage project + IF (project_id = 'clingen-stage') THEN + RETURN; + END IF; + + -- validate the last release date for clinvar_vcv_classifications + CALL `clinvar_ingest.validate_last_release`('clinvar_vcv_classifications', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_vcv_classifications processing. " + validation_message; + RETURN; + END IF; + + -- deleted vcv_classifications (where it exists in clinvar_vcv_classifications (for deleted_release_date is null), but doesn't exist in current data set ) + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_vcv_classifications` cvcvc + SET + deleted_release_date = %T, + deleted_count = deleted_count + 1 + WHERE + cvcvc.deleted_release_date is NULL + AND + NOT EXISTS ( + SELECT + vcvc.vcv_id + FROM `%s.variation_archive_classification` vcvc + LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 + ON + cvs1.label = vcvc.review_status + WHERE + vcvc.vcv_id = cvcvc.vcv_id + AND + vcvc.statement_type IS NOT DISTINCT FROM cvcvc.statement_type + AND + cvs1.rank IS NOT DISTINCT FROM cvcvc.rank + AND + vcvc.interp_date_last_evaluated IS NOT DISTINCT FROM cvcvc.last_evaluated + AND + vcvc.interp_description IS NOT DISTINCT FROM cvcvc.agg_classification_description + AND + vcvc.num_submitters IS NOT DISTINCT FROM cvcvc.num_submitters + AND + vcvc.num_submissions IS NOT DISTINCT FROM cvcvc.num_submissions + AND + vcvc.most_recent_submission IS NOT DISTINCT FROM cvcvc.most_recent_submission + AND + vcvc.clinical_impact_assertion_type IS NOT DISTINCT FROM cvcvc.clinical_impact_assertion_type + AND + vcvc.clinical_impact_clinical_significance IS NOT DISTINCT FROM cvcvc.clinical_impact_clinical_significance + ) + """, release_date, schema_name); + + -- updated variations + EXECUTE IMMEDIATE FORMAT(""" + UPDATE `clinvar_ingest.clinvar_vcv_classifications` cvcvc + SET + end_release_date = %T, + deleted_release_date = NULL + FROM `%s.variation_archive_classification` vcvc + LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 + ON + cvs1.label = vcvc.review_status + WHERE + vcvc.vcv_id = cvcvc.vcv_id + AND + vcvc.statement_type IS NOT DISTINCT FROM cvcvc.statement_type + AND + cvs1.rank IS NOT DISTINCT FROM cvcvc.rank + AND + vcvc.interp_date_last_evaluated IS NOT DISTINCT FROM cvcvc.last_evaluated + AND + vcvc.interp_description IS NOT DISTINCT FROM cvcvc.agg_classification_description + AND + vcvc.num_submitters IS NOT DISTINCT FROM cvcvc.num_submitters + AND + vcvc.num_submissions IS NOT DISTINCT FROM cvcvc.num_submissions + AND + vcvc.most_recent_submission IS NOT DISTINCT FROM cvcvc.most_recent_submission + AND + vcvc.clinical_impact_assertion_type IS NOT DISTINCT FROM cvcvc.clinical_impact_assertion_type + AND + vcvc.clinical_impact_clinical_significance IS NOT DISTINCT FROM cvcvc.clinical_impact_clinical_significance + """, release_date, schema_name); + + -- new variation_archive_classification + EXECUTE IMMEDIATE FORMAT(""" + INSERT INTO `clinvar_ingest.clinvar_vcv_classifications` ( + vcv_id, + statement_type, + rank, + last_evaluated, + agg_classification_description, + num_submitters, + num_submissions, + most_recent_submission, + clinical_impact_assertion_type, + clinical_impact_clinical_significance, + start_release_date, + end_release_date + ) + SELECT + vcvc.vcv_id, + vcvc.statement_type, + cvs1.rank, + vcvc.interp_date_last_evaluated as last_evaluated, + vcvc.interp_description as agg_classification_description, + vcvc.num_submitters, + vcvc.num_submissions, + vcvc.most_recent_submission, + vcvc.clinical_impact_assertion_type, + vcvc.clinical_impact_clinical_significance, + %T as start_release_date, + %T as end_release_date + FROM `%s.variation_archive_classification` vcvc + -- dataset term check in dataset-preparation scripts should assure all statuses are present + -- just in case we should keep outer join to allow null 'rank' to be produced to assure no + -- records are skipped in the final result set. + LEFT JOIN `clinvar_ingest.clinvar_status` cvs1 + ON + cvs1.label = vcvc.review_status + WHERE + NOT EXISTS ( + SELECT cvcvc.vcv_id + FROM `clinvar_ingest.clinvar_vcv_classifications` cvcvc + WHERE + vcvc.vcv_id = cvcvc.vcv_id AND + vcvc.statement_type IS NOT DISTINCT FROM cvcvc.statement_type + AND + cvs1.rank IS NOT DISTINCT FROM cvcvc.rank + AND + vcvc.interp_date_last_evaluated IS NOT DISTINCT FROM cvcvc.last_evaluated + AND + vcvc.interp_description IS NOT DISTINCT FROM cvcvc.agg_classification_description + AND + vcvc.num_submitters IS NOT DISTINCT FROM cvcvc.num_submitters + AND + vcvc.num_submissions IS NOT DISTINCT FROM cvcvc.num_submissions + AND + vcvc.most_recent_submission IS NOT DISTINCT FROM cvcvc.most_recent_submission + AND + vcvc.clinical_impact_assertion_type IS NOT DISTINCT FROM cvcvc.clinical_impact_assertion_type + AND + vcvc.clinical_impact_clinical_significance IS NOT DISTINCT FROM cvcvc.clinical_impact_clinical_significance + ) + """, release_date, release_date, schema_name); + + SET result_message = "clinvar_vcv_classifications processed successfully."; + +END; \ No newline at end of file diff --git a/scripts/temporal-data-collection/05-clinvar-scvs-proc.sql b/scripts/temporal-data-collection/07-clinvar-scvs-proc.sql similarity index 95% rename from scripts/temporal-data-collection/05-clinvar-scvs-proc.sql rename to scripts/temporal-data-collection/07-clinvar-scvs-proc.sql index 6deef46..7826bd0 100644 --- a/scripts/temporal-data-collection/05-clinvar-scvs-proc.sql +++ b/scripts/temporal-data-collection/07-clinvar-scvs-proc.sql @@ -1,10 +1,13 @@ CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_scvs`( schema_name STRING, release_date DATE, - previous_release_date DATE + previous_release_date DATE, + OUT result_message STRING ) BEGIN DECLARE project_id STRING; + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; SET project_id = ( @@ -15,10 +18,15 @@ BEGIN schema_name = 'clinvar_ingest' ); - IF (project_id = 'clingen-stage') THEN + -- validate the last release date clinvar_scvs + CALL `clinvar_ingest.validate_last_release`('clinvar_scvs', previous_release_date, is_valid, validation_message); - -- validate the last release date clinvar_scvs - CALL `clinvar_ingest.validate_last_release`('clinvar_scvs',previous_release_date); + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_scvs processing. " + validation_message; + RETURN; + END IF; + + IF (project_id = 'clingen-stage') THEN -- deletes EXECUTE IMMEDIATE FORMAT(""" @@ -148,9 +156,6 @@ BEGIN ELSE - -- validate the last release date clinvar_scvs - CALL `clinvar_ingest.validate_last_release`('clinvar_scvs',previous_release_date); - -- deletes EXECUTE IMMEDIATE FORMAT(""" UPDATE `clinvar_ingest.clinvar_scvs` cs @@ -306,4 +311,6 @@ BEGIN END IF; + SET result_message = "clinvar_scvs processed successfully."; + END; diff --git a/scripts/temporal-data-collection/06-clinvar-gc-scvs-proc.sql b/scripts/temporal-data-collection/08-clinvar-gc-scvs-proc.sql similarity index 89% rename from scripts/temporal-data-collection/06-clinvar-gc-scvs-proc.sql rename to scripts/temporal-data-collection/08-clinvar-gc-scvs-proc.sql index 1c0b381..56bf77c 100644 --- a/scripts/temporal-data-collection/06-clinvar-gc-scvs-proc.sql +++ b/scripts/temporal-data-collection/08-clinvar-gc-scvs-proc.sql @@ -1,12 +1,20 @@ CREATE OR REPLACE PROCEDURE `clinvar_ingest.clinvar_gc_scvs`( schema_name STRING, release_date DATE, - previous_release_date DATE + previous_release_date DATE, + OUT result_message STRING ) BEGIN + DECLARE is_valid BOOL DEFAULT TRUE; + DECLARE validation_message STRING DEFAULT ''; -- validate the last release date clinvar_gc_scvs - CALL `clinvar_ingest.validate_last_release`('clinvar_gc_scvs',previous_release_date); + CALL `clinvar_ingest.validate_last_release`('clinvar_gc_scvs', previous_release_date, is_valid, validation_message); + + IF NOT is_valid THEN + SET result_message = "Skipping clinvar_gc_scvs processing. " + validation_message; + RETURN; + END IF; -- deletes EXECUTE IMMEDIATE FORMAT(""" @@ -120,4 +128,6 @@ BEGIN ) """, release_date, release_date, schema_name); + SET result_message = "clinvar_gc_scvs processed successfully."; + END; \ No newline at end of file diff --git a/scripts/temporal-data-collection/temporal-data-collection-proc.sql b/scripts/temporal-data-collection/temporal-data-collection-proc.sql index 13c89f3..d970d84 100644 --- a/scripts/temporal-data-collection/temporal-data-collection-proc.sql +++ b/scripts/temporal-data-collection/temporal-data-collection-proc.sql @@ -2,20 +2,42 @@ CREATE OR REPLACE PROCEDURE `clinvar_ingest.temporal_data_collection`( on_date DATE ) BEGIN - FOR rec IN ( - select + DECLARE all_result_messages STRING DEFAULT ''; + DECLARE result_message STRING DEFAULT ''; + DECLARE rec STRUCT; + + -- Declare a cursor to fetch the row + SET rec = ( + SELECT AS STRUCT s.schema_name, s.release_date, s.prev_release_date, - s.next_release_date - FROM clinvar_ingest.schema_on(on_date) as s - ) - DO - CALL `clinvar_ingest.clinvar_genes`(rec.schema_name, rec.release_date, rec.prev_release_date); - CALL `clinvar_ingest.clinvar_submitters`(rec.schema_name, rec.release_date, rec.prev_release_date); - CALL `clinvar_ingest.clinvar_variations`(rec.schema_name, rec.release_date, rec.prev_release_date); - CALL `clinvar_ingest.clinvar_vcvs`(rec.schema_name, rec.release_date, rec.prev_release_date); - CALL `clinvar_ingest.clinvar_scvs`(rec.schema_name, rec.release_date, rec.prev_release_date); - CALL `clinvar_ingest.clinvar_gc_scvs`(rec.schema_name, rec.release_date, rec.prev_release_date); - END FOR; + s.next_release_date + FROM clinvar_ingest.schema_on(on_date) AS s + ); + + CALL `clinvar_ingest.clinvar_genes`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + CALL `clinvar_ingest.clinvar_single_gene_variations`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + CALL `clinvar_ingest.clinvar_submitters`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + CALL `clinvar_ingest.clinvar_variations`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + CALL `clinvar_ingest.clinvar_vcvs`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + CALL `clinvar_ingest.clinvar_scvs`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + CALL `clinvar_ingest.clinvar_gc_scvs`(rec.schema_name, rec.release_date, rec.prev_release_date, result_message); + SET all_result_messages = CONCAT(all_result_messages, '\n', result_message); + + -- Display the concatenated result_message + SELECT all_result_messages AS consolidated_result_message; + END; \ No newline at end of file