From fbd4cde2d35de59678a2f8ad17951b6d166be009 Mon Sep 17 00:00:00 2001 From: Chris Knoll Date: Fri, 12 Apr 2024 13:24:05 -0400 Subject: [PATCH] Added transaction annotation to fetch generation. Added migration to alter views to not return any generations for sources that do not exist. Fixes #2360. --- .../webapi/pathway/PathwayController.java | 1 + ...20240412125600__alter_generation_views.sql | 101 ++++++++++++++++++ 2 files changed, 102 insertions(+) create mode 100644 src/main/resources/db/migration/postgresql/V2.14.1.20240412125600__alter_generation_views.sql diff --git a/src/main/java/org/ohdsi/webapi/pathway/PathwayController.java b/src/main/java/org/ohdsi/webapi/pathway/PathwayController.java index 4d7cd55dc..fdd1c011d 100644 --- a/src/main/java/org/ohdsi/webapi/pathway/PathwayController.java +++ b/src/main/java/org/ohdsi/webapi/pathway/PathwayController.java @@ -364,6 +364,7 @@ public void cancelPathwaysGeneration( @Path("/{id}/generation") @Produces(MediaType.APPLICATION_JSON) @Consumes(MediaType.APPLICATION_JSON) + @Transactional public List getPathwayGenerations( @PathParam("id") final Integer pathwayAnalysisId ) { diff --git a/src/main/resources/db/migration/postgresql/V2.14.1.20240412125600__alter_generation_views.sql b/src/main/resources/db/migration/postgresql/V2.14.1.20240412125600__alter_generation_views.sql new file mode 100644 index 000000000..dfd47456c --- /dev/null +++ b/src/main/resources/db/migration/postgresql/V2.14.1.20240412125600__alter_generation_views.sql @@ -0,0 +1,101 @@ +DROP VIEW ${ohdsiSchema}.cc_generation; +DROP VIEW ${ohdsiSchema}.estimation_analysis_generation; +DROP VIEW ${ohdsiSchema}.pathway_analysis_generation; +DROP VIEW ${ohdsiSchema}.prediction_analysis_generation; + +CREATE OR REPLACE VIEW ${ohdsiSchema}.cc_generation as ( + SELECT + -- Spring batch based + job.job_execution_id id, + job.create_time start_time, + job.end_time end_time, + job.status status, + job.exit_message exit_message, + CAST(cc_id_param.string_val AS INTEGER) cc_id, + CAST(source_param.string_val AS INTEGER) source_id, + -- Generation info based + gen_info.hash_code hash_code, + gen_info.created_by_id created_by_id + FROM ${ohdsiSchema}.batch_job_execution job + JOIN ${ohdsiSchema}.batch_job_execution_params cc_id_param ON job.job_execution_id = cc_id_param.job_execution_id + AND cc_id_param.key_name = 'cohort_characterization_id' + JOIN ${ohdsiSchema}.batch_job_execution_params source_param ON job.job_execution_id = source_param.job_execution_id + AND source_param.key_name = 'source_id' + JOIN ${ohdsiSchema}.source s on s.source_id = CAST(source_param.string_val AS INTEGER) + LEFT JOIN ${ohdsiSchema}.analysis_generation_info gen_info ON job.job_execution_id = gen_info.job_execution_id + ORDER BY start_time DESC +); + +CREATE OR REPLACE VIEW ${ohdsiSchema}.estimation_analysis_generation as + SELECT + job.job_execution_id id, + job.create_time start_time, + job.end_time end_time, + job.status status, + job.exit_message exit_message, + CAST(estimation_id_param.string_val AS INTEGER) estimation_id, + CAST(source_param.string_val AS INTEGER) source_id, + passwd_param.string_val update_password, + -- Generation info based + gen_info.hash_code hash_code, + gen_info.created_by_id created_by_id, + -- Execution info based + exec_info.id analysis_execution_id + FROM ${ohdsiSchema}.batch_job_execution job + JOIN ${ohdsiSchema}.batch_job_execution_params estimation_id_param ON job.job_execution_id = estimation_id_param.job_execution_id + AND estimation_id_param.key_name = 'estimation_analysis_id' + JOIN ${ohdsiSchema}.batch_job_execution_params source_param ON job.job_execution_id = source_param.job_execution_id + AND source_param.key_name = 'source_id' + JOIN ${ohdsiSchema}.batch_job_execution_params passwd_param ON job.job_execution_id = passwd_param.job_execution_id + AND passwd_param.key_name = 'update_password' + JOIN ${ohdsiSchema}.source s on s.source_id = CAST(source_param.string_val AS INTEGER) + LEFT JOIN ${ohdsiSchema}.ee_analysis_status exec_info ON job.job_execution_id = exec_info.job_execution_id + LEFT JOIN ${ohdsiSchema}.analysis_generation_info gen_info ON job.job_execution_id = gen_info.job_execution_id; + +CREATE OR REPLACE VIEW ${ohdsiSchema}.pathway_analysis_generation as + (SELECT + job.job_execution_id id, + job.create_time start_time, + job.end_time end_time, + job.status status, + job.exit_message exit_message, + CAST(pa_id_param.string_val AS INTEGER) pathway_analysis_id, + CAST(source_param.string_val AS INTEGER) source_id, + -- Generation info based + gen_info.hash_code hash_code, + gen_info.created_by_id created_by_id + FROM ${ohdsiSchema}.batch_job_execution job + JOIN ${ohdsiSchema}.batch_job_execution_params pa_id_param ON job.job_execution_id = pa_id_param.job_execution_id + AND pa_id_param.key_name = 'pathway_analysis_id' + JOIN ${ohdsiSchema}.batch_job_execution_params source_param ON job.job_execution_id = source_param.job_execution_id + AND source_param.key_name = 'source_id' + JOIN ${ohdsiSchema}.source s on s.source_id = CAST(source_param.string_val AS INTEGER) + LEFT JOIN ${ohdsiSchema}.analysis_generation_info gen_info + ON job.job_execution_id = gen_info.job_execution_id + ORDER BY start_time DESC); + +CREATE OR REPLACE VIEW ${ohdsiSchema}.prediction_analysis_generation as + SELECT + job.job_execution_id id, + job.create_time start_time, + job.end_time end_time, + job.status status, + job.exit_message exit_message, + CAST(plp_id_param.string_val AS INTEGER) prediction_id, + CAST(source_param.string_val AS INTEGER) source_id, + passwd_param.string_val update_password, + -- Generation info based + gen_info.hash_code hash_code, + gen_info.created_by_id created_by_id, + -- Execution info based + exec_info.id analysis_execution_id + FROM ${ohdsiSchema}.batch_job_execution job + JOIN ${ohdsiSchema}.batch_job_execution_params plp_id_param ON job.job_execution_id = plp_id_param.job_execution_id + AND plp_id_param.key_name = 'prediction_analysis_id' + JOIN ${ohdsiSchema}.batch_job_execution_params source_param ON job.job_execution_id = source_param.job_execution_id + AND source_param.key_name = 'source_id' + JOIN ${ohdsiSchema}.batch_job_execution_params passwd_param ON job.job_execution_id = passwd_param.job_execution_id + AND passwd_param.key_name = 'update_password' + JOIN ${ohdsiSchema}.source s on s.source_id = CAST(source_param.string_val AS INTEGER) + LEFT JOIN ${ohdsiSchema}.ee_analysis_status exec_info ON job.job_execution_id = exec_info.job_execution_id + LEFT JOIN ${ohdsiSchema}.analysis_generation_info gen_info ON job.job_execution_id = gen_info.job_execution_id;