diff --git a/backend/db/migrations/R__0.14.0__CE-101.sql b/backend/db/migrations/R__0.14.0__CE-101.sql index 2e585c72a..1cd15b612 100644 --- a/backend/db/migrations/R__0.14.0__CE-101.sql +++ b/backend/db/migrations/R__0.14.0__CE-101.sql @@ -1,6 +1,7 @@ - CREATE OR replace FUNCTION PUBLIC.insert_complaint_from_staging(_complaint_identifier CHARACTER varying) returns void LANGUAGE plpgsql -AS - $function$ +CREATE OR REPLACE FUNCTION public.insert_complaint_from_staging(_complaint_identifier character varying) + RETURNS void + LANGUAGE plpgsql +AS $function$ declare non_digit_regex CONSTANT text := '[^\d]'; -- used to strip out non-numeric characters from the phone number fields @@ -150,17 +151,6 @@ AS FROM PUBLIC.insert_and_return_code( _webeoc_cos_area_community, 'geoorgutcd' ) INTO _geo_organization_unit_code; - -- convert webeoc species to our species code - _webeoc_species := complaint_data ->> 'species'; - SELECT * - FROM PUBLIC.insert_and_return_code(_webeoc_species, 'speciescd') - INTO _species_code; - - _webeoc_hwcr_complaint_nature_code := complaint_data ->> 'nature_of_complaint'; - SELECT * - FROM PUBLIC.insert_and_return_code( _webeoc_hwcr_complaint_nature_code, 'cmpltntrcd' ) - INTO _hwcr_complaint_nature_code; - -- Insert data into 'complaint' table INSERT INTO PUBLIC.complaint ( @@ -213,7 +203,19 @@ AS _cos_reffered_by_txt ); - IF _report_type = 'HWCR' THEN + IF _report_type = 'HWCR' then + + -- convert webeoc species to our species code + _webeoc_species := complaint_data ->> 'species'; + SELECT * + FROM PUBLIC.insert_and_return_code(_webeoc_species, 'speciescd') + INTO _species_code; + + _webeoc_hwcr_complaint_nature_code := complaint_data ->> 'nature_of_complaint'; + SELECT * + FROM PUBLIC.insert_and_return_code( _webeoc_hwcr_complaint_nature_code, 'cmpltntrcd' ) + INTO _hwcr_complaint_nature_code; + -- Prepare data for 'hwcr_complaint' table _other_attractants_text := complaint_data ->> 'attractant_other_text'; SELECT uuid_generate_v4() @@ -334,29 +336,32 @@ AS RAISE notice 'An unexpected error occurred: %', SQLERRM; UPDATE staging_complaint SET staging_status_code = 'ERROR' - WHERE complaint_identifier = _complaint_identifier; + WHERE complaint_identifier = _complaint_identifier + and staging_status_code = 'PENDING'; END; - $function$ ; + $function$ +; - CREATE OR REPLACE FUNCTION public.insert_and_return_code(webeoc_value character varying, code_table_type character varying) +CREATE OR REPLACE FUNCTION public.insert_and_return_code(webeoc_value character varying, code_table_type character varying) RETURNS character varying LANGUAGE plpgsql AS $function$ DECLARE - truncated_code VARCHAR(10); + new_code VARCHAR(10); -- used in case we're creating a new code + truncated_code varchar(10); -- if we're creating a new code, base it off of the webeoc_value. We'll truncate this and get rid of spaces, and possibly append a number to make it unique live_code_value VARCHAR; current_utc_timestamp TIMESTAMP WITH TIME ZONE := NOW(); target_code_table VARCHAR; column_name VARCHAR; + code_exists BOOLEAN; + suffix VARCHAR(10) := ''; -- Suffix for uniqueness + counter INTEGER := 1; -- Counter for unique code generation + new_display_order INTEGER; -- used for setting the display_order value of the new code BEGIN - -- Truncate and uppercase the webEOC value - truncated_code := UPPER(LEFT(webEOC_value, 10)); + -- Truncate and uppercase the webEOC value, get rid of spaces, and truncate to 9 characters to ensure we have room for adding a number for uniqueness + truncated_code := UPPER(LEFT(regexp_replace(webeoc_value, '\s', '', 'g'), 10)); - IF truncated_code IS NULL OR truncated_code = '' THEN - RETURN NULL; - END IF; - -- Resolve the target code table and column name based on code_table_type CASE code_table_type WHEN 'reprtdbycd' THEN @@ -384,24 +389,63 @@ BEGIN -- Check if the code exists in staging_metadata_mapping SELECT live_data_value INTO live_code_value FROM staging_metadata_mapping - WHERE UPPER(LEFT(staged_data_value, 10)) = truncated_code + WHERE staged_data_value = webEOC_value AND entity_code = code_table_type; -- If the code exists, return the live_data_value IF live_code_value IS NOT NULL THEN RETURN live_code_value; END IF; + - -- Insert the new code into the specified code table - EXECUTE format('INSERT INTO %I (%I, short_description, long_description, active_ind, create_user_id, create_utc_timestamp, update_user_id, update_utc_timestamp, display_order) VALUES ($1, $2, $3, ''Y'', ''webeoc'', $4, ''webeoc'', $4, $5)', target_code_table, column_name) - USING truncated_code, webEOC_value, webEOC_value, current_utc_timestamp, 2; - - -- Insert the new code into staging_metadata_mapping - INSERT INTO staging_metadata_mapping (entity_code, staged_data_value, live_data_value, create_user_id, create_utc_timestamp, update_user_id, update_utc_timestamp) - VALUES (code_table_type, truncated_code, truncated_code, 'webeoc', current_utc_timestamp, 'webeoc', current_utc_timestamp); - - -- Return the newly created code - RETURN truncated_code; + -- We're creating a new code because the webeoc code doesn't exist in staging_metadata_mapping. We want to add this new code to our code tables, as well as the staging_meta_mapping table. + -- Before we create new codes in our code tables, we want to make sure we're not creating a duplicate. If the new code doesn't exist + -- in staging_metamapping, and the code doesn't exist in the code table, then create the code in both tables. + -- If the code doesn't exist in staging_meta_mapping, but does exist in the code table, then create a new unique code + -- in both the staging_meta_mapping table and the code table. + + loop + + -- if a suffix is required, truncate the code to 9 characters so that there's room for the suffix + IF suffix <> '' THEN + truncated_code := LEFT(truncated_code, 9); + END IF; + + -- Append a numeric suffix if necessary + new_code := truncated_code || suffix; + + -- Check if the new_code exists in the specific code table + EXECUTE format('SELECT EXISTS(SELECT 1 FROM %I WHERE %I = $1)', target_code_table, column_name) + INTO code_exists + USING new_code; + + IF NOT code_exists then + + -- Determine the correct display_order for the new code + EXECUTE format('SELECT COALESCE(MAX(display_order) + 1, 1) FROM %I WHERE %I < $1', target_code_table, column_name) + INTO new_display_order + USING new_code; + + -- Re-index the display_orders + EXECUTE format('UPDATE %I SET display_order = display_order + 1 WHERE display_order >= $1', target_code_table) + USING new_display_order; + + -- Insert new code into the specific code table + EXECUTE format('INSERT INTO %I (%I, short_description, long_description, active_ind, create_user_id, create_utc_timestamp, update_user_id, update_utc_timestamp, display_order) VALUES ($1, $2, $3, ''Y'', ''webeoc'', $4, ''webeoc'', $4, $5)', target_code_table, column_name) + USING new_code, webeoc_value, webeoc_value, current_utc_timestamp, new_display_order; + + -- Insert into staging_metadata_mapping + INSERT INTO staging_metadata_mapping (entity_code, staged_data_value, live_data_value, create_user_id, create_utc_timestamp, update_user_id, update_utc_timestamp) + VALUES (code_table_type, webeoc_value, new_code, 'webeoc', current_utc_timestamp, 'webeoc', current_utc_timestamp); + + RETURN new_code; -- Return the new unique code + ELSE + -- If the code exists, increment the suffix and try again + suffix := counter::text; + counter := counter + 1; + END IF; + END LOOP; + END; $function$ -; +; \ No newline at end of file diff --git a/docker-compose.yml b/docker-compose.yml index a0b65cff9..04645b68a 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -102,15 +102,6 @@ services: - "sh" - "-c" - "npm i && npm run start" - environment: - WEBEOC_USERNAME: ${WEBEOC_USERNAME} - WEBEOC_PASSWORD: ${WEBEOC_PASSWORD} - WEBEOC_POSITION: ${WEBEOC_POSITION} - WEBEOC_INCIDENT: ${WEBEOC_INCIDENT} - WEBEOC_URL: ${WEBEOC_URL} - WEBEOC_COMPLAINT_HISTORY_DAYS: ${WEBEOC_COMPLAINT_HISTORY_DAYS} - WEBEOC_CRON_EXPRESSION: "*/1 * * * *" - NATS_HOST: "nats://nats:4222" hostname: webeoc image: registry.access.redhat.com/ubi8/nodejs-18-minimal@sha256:74af9dc2b620022c77fcd712b811f64a03c1444ff1e9b9596a242b2edf3cf96f links: