Skip to content

Commit 61996e3

Browse files
authored
Merge pull request #779 from bcgov/yj
Yj
2 parents c31070b + 2340961 commit 61996e3

File tree

3 files changed

+188
-7
lines changed

3 files changed

+188
-7
lines changed
Lines changed: 172 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,172 @@
1+
DROP PROCEDURE IF EXISTS dss_process_biz_lic_table(lg_id BIGINT);
2+
3+
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_delete(lg_id BIGINT)
4+
LANGUAGE plpgsql
5+
AS $$
6+
DECLARE
7+
source_count int;
8+
unlink_count int;
9+
delete_count int;
10+
BEGIN
11+
-- Exit if temporary table is missing
12+
IF NOT EXISTS (
13+
SELECT 1
14+
FROM pg_tables
15+
WHERE tablename = 'biz_lic_table'
16+
) THEN
17+
RAISE NOTICE 'biz_lic_table does not exist. Exiting procedure.';
18+
RETURN;
19+
END IF;
20+
21+
SELECT COUNT(1) INTO source_count
22+
FROM biz_lic_table
23+
WHERE providing_organization_id = lg_id;
24+
25+
RAISE NOTICE 'Found % source rows', source_count;
26+
27+
-- Unlink before Deletion
28+
MERGE INTO dss_rental_listing AS tgt
29+
USING (
30+
SELECT business_licence_id
31+
FROM dss_business_licence AS dbl
32+
WHERE providing_organization_id = lg_id
33+
AND NOT EXISTS (
34+
SELECT 1 FROM biz_lic_table AS blt
35+
WHERE blt.business_licence_no = dbl.business_licence_no AND blt.providing_organization_id = lg_id)
36+
) AS src
37+
ON (tgt.governing_business_licence_id = src.business_licence_id)
38+
WHEN MATCHED THEN
39+
UPDATE SET
40+
effective_business_licence_no = regexp_replace(regexp_replace(UPPER(tgt.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', ''),
41+
governing_business_licence_id = NULL,
42+
is_changed_business_licence = false;
43+
44+
GET DIAGNOSTICS unlink_count = ROW_COUNT;
45+
46+
RAISE NOTICE 'Unlinked business licences for % listings', unlink_count;
47+
48+
-- Deletion
49+
DELETE FROM dss_business_licence AS dbl
50+
WHERE providing_organization_id = lg_id
51+
AND NOT EXISTS (
52+
SELECT 1 FROM biz_lic_table AS blt
53+
WHERE blt.business_licence_no = dbl.business_licence_no AND blt.providing_organization_id = lg_id);
54+
55+
GET DIAGNOSTICS delete_count = ROW_COUNT;
56+
57+
RAISE NOTICE 'Deleted % business licences', delete_count;
58+
END $$;
59+
60+
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_insert(lg_id BIGINT)
61+
LANGUAGE plpgsql
62+
AS $$
63+
DECLARE
64+
source_count int;
65+
merged_count int;
66+
BEGIN
67+
-- Exit if temporary table is missing
68+
IF NOT EXISTS (
69+
SELECT 1
70+
FROM pg_tables
71+
WHERE tablename = 'biz_lic_table'
72+
) THEN
73+
RAISE NOTICE 'biz_lic_table does not exist. Exiting procedure.';
74+
RETURN;
75+
END IF;
76+
77+
SELECT COUNT(1) INTO source_count
78+
FROM biz_lic_table
79+
WHERE providing_organization_id = lg_id;
80+
81+
RAISE NOTICE 'Found % source rows', source_count;
82+
83+
-- Insert into dss_business_licence from biz_lic_table or update if exists
84+
MERGE INTO dss_business_licence AS tgt
85+
USING (SELECT * FROM biz_lic_table) AS src
86+
ON (tgt.providing_organization_id = src.providing_organization_id AND
87+
tgt.business_licence_no = src.business_licence_no)
88+
WHEN MATCHED THEN UPDATE SET
89+
expiry_dt = src.expiry_dt,
90+
physical_rental_address_txt = src.physical_rental_address_txt,
91+
licence_type_txt = src.licence_type_txt,
92+
restriction_txt = src.restriction_txt,
93+
business_nm = src.business_nm,
94+
mailing_street_address_txt = src.mailing_street_address_txt,
95+
mailing_city_nm = src.mailing_city_nm,
96+
mailing_province_cd = src.mailing_province_cd,
97+
mailing_postal_cd = src.mailing_postal_cd,
98+
business_owner_nm = src.business_owner_nm,
99+
business_owner_phone_no = src.business_owner_phone_no,
100+
business_owner_email_address_dsc = src.business_owner_email_address_dsc,
101+
business_operator_nm = src.business_operator_nm,
102+
business_operator_phone_no = src.business_operator_phone_no,
103+
business_operator_email_address_dsc = src.business_operator_email_address_dsc,
104+
infraction_txt = src.infraction_txt,
105+
infraction_dt = src.infraction_dt,
106+
property_zone_txt = src.property_zone_txt,
107+
available_bedrooms_qty = src.available_bedrooms_qty,
108+
max_guests_allowed_qty = src.max_guests_allowed_qty,
109+
is_principal_residence = src.is_principal_residence,
110+
is_owner_living_onsite = src.is_owner_living_onsite,
111+
is_owner_property_tenant = src.is_owner_property_tenant,
112+
property_folio_no = src.property_folio_no,
113+
property_parcel_identifier_no = src.property_parcel_identifier_no,
114+
property_legal_description_txt = src.property_legal_description_txt,
115+
licence_status_type = src.licence_status_type
116+
WHEN NOT MATCHED THEN INSERT (
117+
business_licence_no, expiry_dt, physical_rental_address_txt, licence_type_txt, restriction_txt,
118+
business_nm, mailing_street_address_txt, mailing_city_nm, mailing_province_cd, mailing_postal_cd,
119+
business_owner_nm, business_owner_phone_no, business_owner_email_address_dsc, business_operator_nm,
120+
business_operator_phone_no, business_operator_email_address_dsc, infraction_txt, infraction_dt,
121+
property_zone_txt, available_bedrooms_qty, max_guests_allowed_qty, is_principal_residence,
122+
is_owner_living_onsite, is_owner_property_tenant, property_folio_no, property_parcel_identifier_no,
123+
property_legal_description_txt, licence_status_type, providing_organization_id)
124+
VALUES (
125+
src.business_licence_no, src.expiry_dt, src.physical_rental_address_txt, src.licence_type_txt, src.restriction_txt,
126+
src.business_nm, src.mailing_street_address_txt, src.mailing_city_nm, src.mailing_province_cd, src.mailing_postal_cd,
127+
src.business_owner_nm, src.business_owner_phone_no, src.business_owner_email_address_dsc, src.business_operator_nm,
128+
src.business_operator_phone_no, src.business_operator_email_address_dsc, src.infraction_txt, src.infraction_dt,
129+
src.property_zone_txt, src.available_bedrooms_qty, src.max_guests_allowed_qty, src.is_principal_residence,
130+
src.is_owner_living_onsite, src.is_owner_property_tenant, src.property_folio_no, src.property_parcel_identifier_no,
131+
src.property_legal_description_txt, src.licence_status_type, src.providing_organization_id);
132+
133+
GET DIAGNOSTICS merged_count = ROW_COUNT;
134+
135+
RAISE NOTICE 'Created or refreshed % business licences', merged_count;
136+
137+
-- Optional: Truncate the temporary table after processing
138+
TRUNCATE TABLE biz_lic_table;
139+
END $$;
140+
141+
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_update(lg_id BIGINT)
142+
LANGUAGE plpgsql
143+
AS $$
144+
DECLARE
145+
linked_count int;
146+
BEGIN
147+
-- Update dss_rental_listing if differing match found
148+
MERGE INTO dss_rental_listing AS tgt
149+
USING (
150+
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
151+
FROM dss_rental_listing drl
152+
JOIN dss_physical_address dpa ON drl.locating_physical_address_id = dpa.physical_address_id
153+
JOIN dss_organization lgs ON lgs.organization_id = dpa.containing_organization_id AND dpa.match_score_amt > 1
154+
LEFT JOIN dss_business_licence dbl ON (
155+
regexp_replace(regexp_replace(UPPER(drl.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', '') =
156+
regexp_replace(regexp_replace(UPPER(dbl.business_licence_no), '[^A-Z0-9]+', '', 'g'), '^0+', '')
157+
AND lgs.managing_organization_id = dbl.providing_organization_id)
158+
WHERE drl.including_rental_listing_report_id IS NULL
159+
AND COALESCE(drl.governing_business_licence_id, -1) != COALESCE(dbl.business_licence_id, -1)
160+
AND NOT COALESCE(drl.is_changed_business_licence, false)
161+
AND lgs.managing_organization_id = lg_id
162+
) AS src
163+
ON (tgt.rental_listing_id = src.rental_listing_id)
164+
WHEN MATCHED THEN
165+
UPDATE SET
166+
effective_business_licence_no = src.normalized_business_licence_no,
167+
governing_business_licence_id = src.business_licence_id;
168+
169+
GET DIAGNOSTICS linked_count = ROW_COUNT;
170+
171+
RAISE NOTICE 'Linked business licences for % listings', linked_count;
172+
END $$;

server/StrDss.Api/Controllers/DelistingController.cs

Lines changed: 12 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -215,21 +215,26 @@ public async Task<ActionResult> SendBatchtakedownNotice([FromForm] BatchTakedown
215215
[HttpPost("complianceorders/preview", Name = "GetComplianceOrdersFromListingPreview")]
216216
public async Task<ActionResult> GetComplianceOrdersFromListingPreview(ComplianceOrderDto[] requests)
217217
{
218-
await Task.CompletedTask;
218+
var (errors, preview) = await _delistingService.GetComplianceOrdersFromListingPreviewAsync(requests);
219219

220-
var preview = new EmailPreview
220+
if (errors.Count > 0)
221221
{
222-
Content = "To: john.doe@my.email, jane.smith@my.email<br/><br/><br/>Bcc: young-jin.chung@gov.bc.ca<br/><br/>\r\nDear Host,<br/><br/>\r\nThis message has been sent to you by B.C.'s Short-Term Rental Compliance Unit regarding your short-term rental<br/>\r\nlisting: <b>https://example.com/1000012/</b><br/><br/>\r\ntesting<br/>\r\n"
223-
};
222+
return ValidationUtils.GetValidationErrorResult(errors, ControllerContext);
223+
}
224224

225225
return Ok(preview);
226226
}
227227

228228
[ApiAuthorize(Permissions.ProvinceAction)]
229-
[HttpPost("complianceorders", Name = "CreateComplianceOrdersFromListingPreview")]
230-
public async Task<ActionResult> CreateComplianceOrdersFromListingPreview(ComplianceOrderDto[] requests)
229+
[HttpPost("complianceorders", Name = "CreateComplianceOrdersFromListing")]
230+
public async Task<ActionResult> CreateComplianceOrdersFromListing(ComplianceOrderDto[] requests)
231231
{
232-
await Task.CompletedTask;
232+
var errors = await _delistingService.CreateComplianceOrdersFromListingAsync(requests);
233+
234+
if (errors.Count > 0)
235+
{
236+
return ValidationUtils.GetValidationErrorResult(errors, ControllerContext);
237+
}
233238

234239
return NoContent();
235240
}

server/StrDss.Common/CommonUtils.cs

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -76,6 +76,10 @@ public static string SanitizeAndUppercaseString(string input)
7676
{
7777
if (string.IsNullOrWhiteSpace(input)) return "";
7878

79+
// Remove leading zeroes
80+
input = Regex.Replace(input, @"^0+", "");
81+
82+
// Remove non-alphanumeric characters and convert to uppercase
7983
return Regex.Replace(input, @"[^a-zA-Z0-9]", "").ToUpper();
8084
}
8185

0 commit comments

Comments
 (0)