Skip to content

Commit 8c64ca0

Browse files
authored
Merge pull request #624 from larsenle/main
DSS-771 DB: Updates for BL linking/unlinking
2 parents 27d5acb + 22faa62 commit 8c64ca0

File tree

1 file changed

+15
-38
lines changed

1 file changed

+15
-38
lines changed

database/ddl/STR_DSS_Routines_Sprint_13.sql

Lines changed: 15 additions & 38 deletions
Original file line numberDiff line numberDiff line change
@@ -1,12 +1,12 @@
1+
DROP PROCEDURE IF EXISTS dss_process_biz_lic_table(lg_id BIGINT);
2+
13
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_delete(lg_id BIGINT)
24
LANGUAGE plpgsql
35
AS $$
46
DECLARE
57
source_count int;
68
unlink_count int;
79
delete_count int;
8-
merged_count int;
9-
linked_count int;
1010
BEGIN
1111
-- Exit if temporary table is missing
1212
IF NOT EXISTS (
@@ -36,7 +36,10 @@ BEGIN
3636
) AS src
3737
ON (tgt.governing_business_licence_id = src.business_licence_id)
3838
WHEN MATCHED THEN
39-
UPDATE SET governing_business_licence_id = NULL;
39+
UPDATE SET
40+
effective_business_licence_no = regexp_replace(UPPER(tgt.business_licence_no), '[^A-Z0-9]+', '', 'g'),
41+
governing_business_licence_id = NULL,
42+
is_changed_business_licence = false;
4043

4144
GET DIAGNOSTICS unlink_count = ROW_COUNT;
4245

@@ -54,16 +57,12 @@ BEGIN
5457
RAISE NOTICE 'Deleted % business licences', delete_count;
5558
END $$;
5659

57-
5860
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_insert(lg_id BIGINT)
5961
LANGUAGE plpgsql
6062
AS $$
6163
DECLARE
6264
source_count int;
63-
unlink_count int;
64-
delete_count int;
6565
merged_count int;
66-
linked_count int;
6766
BEGIN
6867
-- Exit if temporary table is missing
6968
IF NOT EXISTS (
@@ -134,61 +133,39 @@ BEGIN
134133
GET DIAGNOSTICS merged_count = ROW_COUNT;
135134

136135
RAISE NOTICE 'Created or refreshed % business licences', merged_count;
136+
137+
-- Optional: Truncate the temporary table after processing
138+
TRUNCATE TABLE biz_lic_table;
137139
END $$;
138140

139141
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_update(lg_id BIGINT)
140142
LANGUAGE plpgsql
141143
AS $$
142144
DECLARE
143-
source_count int;
144-
unlink_count int;
145-
delete_count int;
146-
merged_count int;
147145
linked_count int;
148146
BEGIN
149-
-- Exit if temporary table is missing
150-
IF NOT EXISTS (
151-
SELECT 1
152-
FROM pg_tables
153-
WHERE tablename = 'biz_lic_table'
154-
) THEN
155-
RAISE NOTICE 'biz_lic_table does not exist. Exiting procedure.';
156-
RETURN;
157-
END IF;
158-
159-
SELECT COUNT(1) INTO source_count
160-
FROM biz_lic_table
161-
WHERE providing_organization_id = lg_id;
162-
163-
RAISE NOTICE 'Found % source rows', source_count;
164-
165-
166-
167147
-- Update dss_rental_listing if differing match found
168148
MERGE INTO dss_rental_listing AS tgt
169149
USING (
170-
SELECT drl.rental_listing_id, dbl.business_licence_id
150+
SELECT drl.rental_listing_id, dbl.business_licence_id, regexp_replace(UPPER(drl.business_licence_no), '[^A-Z0-9]+', '', 'g') AS normalized_business_licence_no
171151
FROM dss_rental_listing drl
172152
JOIN dss_physical_address dpa ON drl.locating_physical_address_id = dpa.physical_address_id
173153
JOIN dss_organization lgs ON lgs.organization_id = dpa.containing_organization_id AND dpa.match_score_amt > 1
174154
LEFT JOIN dss_business_licence dbl ON (
175155
regexp_replace(UPPER(drl.business_licence_no), '[^A-Z0-9]+', '', 'g') = regexp_replace(UPPER(dbl.business_licence_no), '[^A-Z0-9]+', '', 'g')
176156
AND lgs.managing_organization_id = dbl.providing_organization_id)
177-
WHERE drl.including_rental_listing_report_id IS NULL
157+
WHERE drl.including_rental_listing_report_id IS NULL
178158
AND COALESCE(drl.governing_business_licence_id, -1) != COALESCE(dbl.business_licence_id, -1)
159+
AND NOT COALESCE(drl.is_changed_business_licence, false)
179160
AND lgs.managing_organization_id = lg_id
180161
) AS src
181162
ON (tgt.rental_listing_id = src.rental_listing_id)
182163
WHEN MATCHED THEN
183-
UPDATE SET governing_business_licence_id = src.business_licence_id;
164+
UPDATE SET
165+
effective_business_licence_no = src.normalized_business_licence_no,
166+
governing_business_licence_id = src.business_licence_id;
184167

185168
GET DIAGNOSTICS linked_count = ROW_COUNT;
186169

187170
RAISE NOTICE 'Linked business licences for % listings', linked_count;
188-
189-
-- Optional: Truncate the temporary table after processing
190-
TRUNCATE TABLE biz_lic_table;
191-
192-
-- Notify of completion
193-
RAISE NOTICE 'Data has been processed from biz_lic_table to dss_business_licence for lg_id %', lg_id;
194171
END $$;

0 commit comments

Comments
 (0)