@@ -1024,6 +1024,9 @@ UNION ALL
10241024-- MALS2-69 - Enable search by Premises ID
10251025-- --
10261026-- Add an array of Premises IDs to each licence returned by the licence summary view
1027+ -- Add a display_premises_id field to show the best matched premises ID based on address, or fallback to lowest site.id
1028+
1029+ CREATE EXTENSION IF NOT EXISTS fuzzystrmatch;
10271030
10281031CREATE OR REPLACE VIEW mals_app .mal_licence_summary_vw
10291032AS SELECT lic .id AS licence_id,
@@ -1086,25 +1089,54 @@ AS SELECT lic.id AS licence_id,
10861089 lic .print_certificate ,
10871090 lic .print_renewal ,
10881091 lic .print_dairy_infraction ,
1089- COALESCE(
1090- (
1091- SELECT array_agg(DISTINCT clean_pid ORDER BY clean_pid)
1092- FROM (
1093- SELECT NULLIF(BTRIM(site .premises_id ::text ), ' ' ) AS clean_pid
1094- FROM mals_app .mal_site site
1095- WHERE site .licence_id = lic .id
1096- ) cleaned
1097- WHERE clean_pid IS NOT NULL
1098- ),
1099- ARRAY[]::varchar []
1100- ) AS premises_ids
1101- FROM mals_app .mal_licence lic
1102- JOIN mals_app .mal_licence_type_lu lictyp ON lic .licence_type_id = lictyp .id
1103- JOIN mals_app .mal_status_code_lu stat ON lic .status_code_id = stat .id
1104- LEFT JOIN mals_app .mal_registrant reg ON lic .primary_registrant_id = reg .id
1105- LEFT JOIN mals_app .mal_region_lu rgn ON lic .region_id = rgn .id
1106- LEFT JOIN mals_app .mal_regional_district_lu dist ON lic .regional_district_id = dist .id
1107- LEFT JOIN mals_app .mal_licence_species_code_lu sp ON lic .species_code_id = sp .id ;
1092+
1093+ -- All premises IDs
1094+ COALESCE((
1095+ SELECT array_agg(DISTINCT cleaned .clean_pid ORDER BY cleaned .clean_pid )
1096+ FROM (SELECT NULLIF(btrim(site .premises_id ::text ), ' ' ) AS clean_pid
1097+ FROM mals_app .mal_site site
1098+ WHERE site .licence_id = lic .id ) cleaned
1099+ WHERE cleaned .clean_pid IS NOT NULL
1100+ ), ARRAY[]::text []) AS premises_ids,
1101+
1102+ -- address match -> lowest site.id fallback
1103+ COALESCE(
1104+ matched_site .premises_id ,
1105+ fallback_site .premises_id
1106+ )::text AS display_premises_id
1107+
1108+ FROM mals_app .mal_licence lic
1109+ JOIN mals_app .mal_licence_type_lu lictyp ON lic .licence_type_id = lictyp .id
1110+ JOIN mals_app .mal_status_code_lu stat ON lic .status_code_id = stat .id
1111+ LEFT JOIN mals_app .mal_registrant reg ON lic .primary_registrant_id = reg .id
1112+ LEFT JOIN mals_app .mal_region_lu rgn ON lic .region_id = rgn .id
1113+ LEFT JOIN mals_app .mal_regional_district_lu dist ON lic .regional_district_id = dist .id
1114+ LEFT JOIN mals_app .mal_licence_species_code_lu sp ON lic .species_code_id = sp .id
1115+
1116+ -- best address match using soundex + house number
1117+ LEFT JOIN LATERAL (
1118+ SELECT site .premises_id
1119+ FROM mals_app .mal_site site
1120+ WHERE site .licence_id = lic .id
1121+ AND site .premises_id IS NOT NULL
1122+ AND soundex(site .address_line_1 ) = soundex(
1123+ COALESCE(lic .address_line_1 , lic .mail_address_line_1 )
1124+ )
1125+ AND NULLIF(REGEXP_REPLACE(site .address_line_1 , ' \D .*$' , ' ' ), ' ' )
1126+ = NULLIF(REGEXP_REPLACE(COALESCE(lic .address_line_1 , lic .mail_address_line_1 ), ' \D .*$' , ' ' ), ' ' )
1127+ ORDER BY site .id
1128+ LIMIT 1
1129+ ) matched_site ON true
1130+
1131+ -- fallback on any site with premises_id, lowest ID is chosen
1132+ LEFT JOIN LATERAL (
1133+ SELECT site .premises_id
1134+ FROM mals_app .mal_site site
1135+ WHERE site .licence_id = lic .id
1136+ AND site .premises_id IS NOT NULL
1137+ ORDER BY site .id
1138+ LIMIT 1
1139+ ) fallback_site ON matched_site .premises_id IS NULL ;
11081140
11091141-- --
11101142-- MALS2-68/70 - Display the Premises ID field in the registrant's sites list / search results
0 commit comments