|
| 1 | +/* Sprint 13 View Changes to STR DSS */ |
| 2 | + |
| 3 | +drop view if exists dss_rental_listing_vw; |
| 4 | + |
| 5 | +CREATE OR REPLACE VIEW dss_rental_listing_vw AS select drl.rental_listing_id |
| 6 | + , dlst.listing_status_type |
| 7 | + , dlst.listing_status_type_nm |
| 8 | + , dlst.listing_status_sort_no |
| 9 | + , (select max(drlr.report_period_ym) |
| 10 | + from dss_rental_listing drl2 |
| 11 | + join dss_rental_listing_report drlr on drlr.rental_listing_report_id=drl2.including_rental_listing_report_id |
| 12 | + where drl2.offering_organization_id=drl.offering_organization_id and drl2.platform_listing_no=drl.platform_listing_no |
| 13 | + ) as latest_report_period_ym |
| 14 | + , drl.is_active |
| 15 | + , drl.is_new |
| 16 | + , drl.is_taken_down |
| 17 | + , drl.is_lg_transferred |
| 18 | + , drl.is_changed_address |
| 19 | + , drl.offering_organization_id |
| 20 | + , org.organization_cd as offering_organization_cd |
| 21 | + , org.organization_nm as offering_organization_nm |
| 22 | + , drl.platform_listing_no |
| 23 | + , drl.platform_listing_url |
| 24 | + , dpa.original_address_txt |
| 25 | + , dpa.is_match_corrected |
| 26 | + , dpa.is_match_verified |
| 27 | + , dpa.match_score_amt |
| 28 | + , dpa.match_address_txt |
| 29 | + , dpa.province_cd as address_sort_1_province_cd |
| 30 | + , dpa.locality_nm as address_sort_2_locality_nm |
| 31 | + , dpa.locality_type_dsc as address_sort_3_locality_type_dsc |
| 32 | + , dpa.street_nm as address_sort_4_street_nm |
| 33 | + , dpa.street_type_dsc as address_sort_5_street_type_dsc |
| 34 | + , dpa.street_direction_dsc as address_sort_6_street_direction_dsc |
| 35 | + , dpa.civic_no as address_sort_7_civic_no |
| 36 | + , dpa.unit_no as address_sort_8_unit_no |
| 37 | + , (select string_agg(full_nm,' ; ') from dss_rental_listing_contact drlc where drlc.contacted_through_rental_listing_id=drl.rental_listing_id) as listing_contact_names_txt |
| 38 | + , lg.organization_id as managing_organization_id |
| 39 | + , lg.organization_nm as managing_organization_nm |
| 40 | + , lgs.economic_region_dsc |
| 41 | + , lgs.is_principal_residence_required |
| 42 | + , lgs.is_business_licence_required |
| 43 | + , drl.is_entire_unit |
| 44 | + , drl.available_bedrooms_qty |
| 45 | + , drl.nights_booked_qty as nights_booked_ytd_qty |
| 46 | + , drl.separate_reservations_qty as separate_reservations_ytd_qty |
| 47 | + , drl.business_licence_no |
| 48 | + , drl.bc_registry_no |
| 49 | + , demt.email_message_type_nm as last_action_nm |
| 50 | + , dem.message_delivery_dtm as last_action_dtm |
| 51 | + , dbl.business_licence_id |
| 52 | + , dbl.business_licence_no as business_licence_no_matched |
| 53 | + , dbl.expiry_dt as business_licence_expiry_dt |
| 54 | + , dbl.licence_status_type |
| 55 | + , drl.effective_business_licence_no |
| 56 | + , drl.effective_host_nm |
| 57 | + , drl.is_changed_business_licence |
| 58 | +FROM dss_rental_listing drl |
| 59 | +join dss_organization org on org.organization_id=drl.offering_organization_id |
| 60 | +LEFT JOIN dss_listing_status_type dlst on drl.listing_status_type=dlst.listing_status_type |
| 61 | +LEFT JOIN dss_physical_address dpa on drl.locating_physical_address_id=dpa.physical_address_id |
| 62 | +left join dss_organization lgs on lgs.organization_id=dpa.containing_organization_id and dpa.match_score_amt>1 |
| 63 | +left join dss_organization lg on lgs.managing_organization_id=lg.organization_id |
| 64 | +LEFT JOIN dss_email_message dem on dem.email_message_id = (select msg.email_message_id from dss_email_message msg where msg.concerned_with_rental_listing_id=drl.rental_listing_id order by msg.message_delivery_dtm desc limit 1) |
| 65 | +LEFT JOIN dss_email_message_type demt on dem.email_message_type=demt.email_message_type |
| 66 | +LEFT join dss_business_licence dbl on drl.governing_business_licence_id = dbl.business_licence_id |
| 67 | +where drl.including_rental_listing_report_id is null; |
0 commit comments