1
+ DROP PROCEDURE IF EXISTS dss_process_biz_lic_table(lg_id BIGINT );
2
+
1
3
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_delete(lg_id BIGINT )
2
4
LANGUAGE plpgsql
3
5
AS $$
4
6
DECLARE
5
7
source_count int ;
6
8
unlink_count int ;
7
9
delete_count int ;
8
- merged_count int ;
9
- linked_count int ;
10
10
BEGIN
11
11
-- Exit if temporary table is missing
12
12
IF NOT EXISTS (
36
36
) AS src
37
37
ON (tgt .governing_business_licence_id = src .business_licence_id )
38
38
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;
40
43
41
44
GET DIAGNOSTICS unlink_count = ROW_COUNT;
42
45
@@ -54,16 +57,12 @@ BEGIN
54
57
RAISE NOTICE ' Deleted % business licences' , delete_count;
55
58
END $$;
56
59
57
-
58
60
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_insert(lg_id BIGINT )
59
61
LANGUAGE plpgsql
60
62
AS $$
61
63
DECLARE
62
64
source_count int ;
63
- unlink_count int ;
64
- delete_count int ;
65
65
merged_count int ;
66
- linked_count int ;
67
66
BEGIN
68
67
-- Exit if temporary table is missing
69
68
IF NOT EXISTS (
@@ -134,61 +133,39 @@ BEGIN
134
133
GET DIAGNOSTICS merged_count = ROW_COUNT;
135
134
136
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;
137
139
END $$;
138
140
139
141
CREATE OR REPLACE PROCEDURE dss_process_biz_lic_table_update(lg_id BIGINT )
140
142
LANGUAGE plpgsql
141
143
AS $$
142
144
DECLARE
143
- source_count int ;
144
- unlink_count int ;
145
- delete_count int ;
146
- merged_count int ;
147
145
linked_count int ;
148
146
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
-
167
147
-- Update dss_rental_listing if differing match found
168
148
MERGE INTO dss_rental_listing AS tgt
169
149
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
171
151
FROM dss_rental_listing drl
172
152
JOIN dss_physical_address dpa ON drl .locating_physical_address_id = dpa .physical_address_id
173
153
JOIN dss_organization lgs ON lgs .organization_id = dpa .containing_organization_id AND dpa .match_score_amt > 1
174
154
LEFT JOIN dss_business_licence dbl ON (
175
155
regexp_replace(UPPER (drl .business_licence_no ), ' [^A-Z0-9]+' , ' ' , ' g' ) = regexp_replace(UPPER (dbl .business_licence_no ), ' [^A-Z0-9]+' , ' ' , ' g' )
176
156
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
178
158
AND COALESCE(drl .governing_business_licence_id , - 1 ) != COALESCE(dbl .business_licence_id , - 1 )
159
+ AND NOT COALESCE(drl .is_changed_business_licence , false)
179
160
AND lgs .managing_organization_id = lg_id
180
161
) AS src
181
162
ON (tgt .rental_listing_id = src .rental_listing_id )
182
163
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 ;
184
167
185
168
GET DIAGNOSTICS linked_count = ROW_COUNT;
186
169
187
170
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;
194
171
END $$;
0 commit comments