From 0873d5bcfb9f9904b6ca23a1ba4a38f62732a809 Mon Sep 17 00:00:00 2001 From: ychung-mot Date: Thu, 7 Nov 2024 10:27:19 -0800 Subject: [PATCH 1/2] feat(dss-939) --- database/ddl/STR_DSS_Routines_Sprint_18.sql | 172 ++++++++++++++++++++ server/StrDss.Common/CommonUtils.cs | 4 + 2 files changed, 176 insertions(+) create mode 100644 database/ddl/STR_DSS_Routines_Sprint_18.sql diff --git a/database/ddl/STR_DSS_Routines_Sprint_18.sql b/database/ddl/STR_DSS_Routines_Sprint_18.sql new file mode 100644 index 00000000..19ce0512 --- /dev/null +++ b/database/ddl/STR_DSS_Routines_Sprint_18.sql @@ -0,0 +1,172 @@ +DROP PROCEDURE IF EXISTS dss_process_biz_lic_table(lg_id BIGINT); + +CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_delete(lg_id BIGINT) +LANGUAGE plpgsql +AS $$ +DECLARE + source_count int; + unlink_count int; + delete_count int; +BEGIN + -- Exit if temporary table is missing + IF NOT EXISTS ( + SELECT 1 + FROM pg_tables + WHERE tablename = 'biz_lic_table' + ) THEN + RAISE NOTICE 'biz_lic_table does not exist. Exiting procedure.'; + RETURN; + END IF; + + SELECT COUNT(1) INTO source_count + FROM biz_lic_table + WHERE providing_organization_id = lg_id; + + RAISE NOTICE 'Found % source rows', source_count; + + -- Unlink before Deletion + MERGE INTO dss_rental_listing AS tgt + USING ( + SELECT business_licence_id + FROM dss_business_licence AS dbl + WHERE providing_organization_id = lg_id + AND NOT EXISTS ( + SELECT 1 FROM biz_lic_table AS blt + WHERE blt.business_licence_no = dbl.business_licence_no AND blt.providing_organization_id = lg_id) + ) AS src + ON (tgt.governing_business_licence_id = src.business_licence_id) + WHEN MATCHED THEN + UPDATE SET + effective_business_licence_no = regexp_replace(regexp_replace(UPPER(tgt.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', ''), + governing_business_licence_id = NULL, + is_changed_business_licence = false; + + GET DIAGNOSTICS unlink_count = ROW_COUNT; + + RAISE NOTICE 'Unlinked business licences for % listings', unlink_count; + + -- Deletion + DELETE FROM dss_business_licence AS dbl + WHERE providing_organization_id = lg_id + AND NOT EXISTS ( + SELECT 1 FROM biz_lic_table AS blt + WHERE blt.business_licence_no = dbl.business_licence_no AND blt.providing_organization_id = lg_id); + + GET DIAGNOSTICS delete_count = ROW_COUNT; + + RAISE NOTICE 'Deleted % business licences', delete_count; +END $$; + +CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_insert(lg_id BIGINT) +LANGUAGE plpgsql +AS $$ +DECLARE + source_count int; + merged_count int; +BEGIN + -- Exit if temporary table is missing + IF NOT EXISTS ( + SELECT 1 + FROM pg_tables + WHERE tablename = 'biz_lic_table' + ) THEN + RAISE NOTICE 'biz_lic_table does not exist. Exiting procedure.'; + RETURN; + END IF; + + SELECT COUNT(1) INTO source_count + FROM biz_lic_table + WHERE providing_organization_id = lg_id; + + RAISE NOTICE 'Found % source rows', source_count; + + -- Insert into dss_business_licence from biz_lic_table or update if exists + MERGE INTO dss_business_licence AS tgt + USING (SELECT * FROM biz_lic_table) AS src + ON (tgt.providing_organization_id = src.providing_organization_id AND + tgt.business_licence_no = src.business_licence_no) + WHEN MATCHED THEN UPDATE SET + expiry_dt = src.expiry_dt, + physical_rental_address_txt = src.physical_rental_address_txt, + licence_type_txt = src.licence_type_txt, + restriction_txt = src.restriction_txt, + business_nm = src.business_nm, + mailing_street_address_txt = src.mailing_street_address_txt, + mailing_city_nm = src.mailing_city_nm, + mailing_province_cd = src.mailing_province_cd, + mailing_postal_cd = src.mailing_postal_cd, + business_owner_nm = src.business_owner_nm, + business_owner_phone_no = src.business_owner_phone_no, + business_owner_email_address_dsc = src.business_owner_email_address_dsc, + business_operator_nm = src.business_operator_nm, + business_operator_phone_no = src.business_operator_phone_no, + business_operator_email_address_dsc = src.business_operator_email_address_dsc, + infraction_txt = src.infraction_txt, + infraction_dt = src.infraction_dt, + property_zone_txt = src.property_zone_txt, + available_bedrooms_qty = src.available_bedrooms_qty, + max_guests_allowed_qty = src.max_guests_allowed_qty, + is_principal_residence = src.is_principal_residence, + is_owner_living_onsite = src.is_owner_living_onsite, + is_owner_property_tenant = src.is_owner_property_tenant, + property_folio_no = src.property_folio_no, + property_parcel_identifier_no = src.property_parcel_identifier_no, + property_legal_description_txt = src.property_legal_description_txt, + licence_status_type = src.licence_status_type + WHEN NOT MATCHED THEN INSERT ( + business_licence_no, expiry_dt, physical_rental_address_txt, licence_type_txt, restriction_txt, + business_nm, mailing_street_address_txt, mailing_city_nm, mailing_province_cd, mailing_postal_cd, + business_owner_nm, business_owner_phone_no, business_owner_email_address_dsc, business_operator_nm, + business_operator_phone_no, business_operator_email_address_dsc, infraction_txt, infraction_dt, + property_zone_txt, available_bedrooms_qty, max_guests_allowed_qty, is_principal_residence, + is_owner_living_onsite, is_owner_property_tenant, property_folio_no, property_parcel_identifier_no, + property_legal_description_txt, licence_status_type, providing_organization_id) + VALUES ( + src.business_licence_no, src.expiry_dt, src.physical_rental_address_txt, src.licence_type_txt, src.restriction_txt, + src.business_nm, src.mailing_street_address_txt, src.mailing_city_nm, src.mailing_province_cd, src.mailing_postal_cd, + src.business_owner_nm, src.business_owner_phone_no, src.business_owner_email_address_dsc, src.business_operator_nm, + src.business_operator_phone_no, src.business_operator_email_address_dsc, src.infraction_txt, src.infraction_dt, + src.property_zone_txt, src.available_bedrooms_qty, src.max_guests_allowed_qty, src.is_principal_residence, + src.is_owner_living_onsite, src.is_owner_property_tenant, src.property_folio_no, src.property_parcel_identifier_no, + src.property_legal_description_txt, src.licence_status_type, src.providing_organization_id); + + GET DIAGNOSTICS merged_count = ROW_COUNT; + + RAISE NOTICE 'Created or refreshed % business licences', merged_count; + + -- Optional: Truncate the temporary table after processing + TRUNCATE TABLE biz_lic_table; +END $$; + +CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_update(lg_id BIGINT) +LANGUAGE plpgsql +AS $$ +DECLARE + linked_count int; +BEGIN + -- Update dss_rental_listing if differing match found + MERGE INTO dss_rental_listing AS tgt + USING ( + SELECT drl.rental_listing_id, dbl.business_licence_id, regexp_replace(regexp_replace(UPPER(drl.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', '') AS normalized_business_licence_no + FROM dss_rental_listing drl + JOIN dss_physical_address dpa ON drl.locating_physical_address_id = dpa.physical_address_id + JOIN dss_organization lgs ON lgs.organization_id = dpa.containing_organization_id AND dpa.match_score_amt > 1 + LEFT JOIN dss_business_licence dbl ON ( + regexp_replace(regexp_replace(UPPER(drl.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', '') = + regexp_replace(regexp_replace(UPPER(dbl.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', '') + AND lgs.managing_organization_id = dbl.providing_organization_id) + WHERE drl.including_rental_listing_report_id IS NULL + AND COALESCE(drl.governing_business_licence_id, -1) != COALESCE(dbl.business_licence_id, -1) + AND NOT COALESCE(drl.is_changed_business_licence, false) + AND lgs.managing_organization_id = lg_id + ) AS src + ON (tgt.rental_listing_id = src.rental_listing_id) + WHEN MATCHED THEN + UPDATE SET + effective_business_licence_no = src.normalized_business_licence_no, + governing_business_licence_id = src.business_licence_id; + + GET DIAGNOSTICS linked_count = ROW_COUNT; + + RAISE NOTICE 'Linked business licences for % listings', linked_count; +END $$; \ No newline at end of file diff --git a/server/StrDss.Common/CommonUtils.cs b/server/StrDss.Common/CommonUtils.cs index be68df89..ede73239 100644 --- a/server/StrDss.Common/CommonUtils.cs +++ b/server/StrDss.Common/CommonUtils.cs @@ -76,6 +76,10 @@ public static string SanitizeAndUppercaseString(string input) { if (string.IsNullOrWhiteSpace(input)) return ""; + // Remove leading zeroes + input = Regex.Replace(input, @"^0+", ""); + + // Remove non-alphanumeric characters and convert to uppercase return Regex.Replace(input, @"[^a-zA-Z0-9]", "").ToUpper(); } From 2340961a6591a753a538e72a7b73fb02bfde4a76 Mon Sep 17 00:00:00 2001 From: ychung-mot Date: Tue, 12 Nov 2024 08:02:16 -0800 Subject: [PATCH 2/2] chore: compliace order --- .../Controllers/DelistingController.cs | 19 ++++++++++++------- 1 file changed, 12 insertions(+), 7 deletions(-) diff --git a/server/StrDss.Api/Controllers/DelistingController.cs b/server/StrDss.Api/Controllers/DelistingController.cs index 86882661..e0bc83ee 100644 --- a/server/StrDss.Api/Controllers/DelistingController.cs +++ b/server/StrDss.Api/Controllers/DelistingController.cs @@ -215,21 +215,26 @@ public async Task SendBatchtakedownNotice([FromForm] BatchTakedown [HttpPost("complianceorders/preview", Name = "GetComplianceOrdersFromListingPreview")] public async Task GetComplianceOrdersFromListingPreview(ComplianceOrderDto[] requests) { - await Task.CompletedTask; + var (errors, preview) = await _delistingService.GetComplianceOrdersFromListingPreviewAsync(requests); - var preview = new EmailPreview + if (errors.Count > 0) { - Content = "To: john.doe@my.email, jane.smith@my.email


Bcc: young-jin.chung@gov.bc.ca

\r\nDear Host,

\r\nThis message has been sent to you by B.C.'s Short-Term Rental Compliance Unit regarding your short-term rental
\r\nlisting: https://example.com/1000012/

\r\ntesting
\r\n" - }; + return ValidationUtils.GetValidationErrorResult(errors, ControllerContext); + } return Ok(preview); } [ApiAuthorize(Permissions.ProvinceAction)] - [HttpPost("complianceorders", Name = "CreateComplianceOrdersFromListingPreview")] - public async Task CreateComplianceOrdersFromListingPreview(ComplianceOrderDto[] requests) + [HttpPost("complianceorders", Name = "CreateComplianceOrdersFromListing")] + public async Task CreateComplianceOrdersFromListing(ComplianceOrderDto[] requests) { - await Task.CompletedTask; + var errors = await _delistingService.CreateComplianceOrdersFromListingAsync(requests); + + if (errors.Count > 0) + { + return ValidationUtils.GetValidationErrorResult(errors, ControllerContext); + } return NoContent(); }