diff --git a/models/intermediate/resolutions/int_resolutions__incidents.sql b/models/intermediate/resolutions/int_resolutions__incidents.sql new file mode 100644 index 0000000..3f31b6c --- /dev/null +++ b/models/intermediate/resolutions/int_resolutions__incidents.sql @@ -0,0 +1,256 @@ +with + stg_resolutions__incidents as ( + select * from {{ ref("stg_resolutions__incidents") }} + ), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), + int_daily_currency_exchange_rates as ( + select * from {{ ref("int_daily_currency_exchange_rates") }} + ), + logs_timeline as ( + select + id_incident, + ( + select (comment ->> 'CreatedDate')::timestamp + from jsonb_array_elements(comment_logs::jsonb) comment + order by (comment ->> 'CreatedDate')::timestamp + limit 1 + ) as first_comment_at_utc, + ( + select (comment ->> 'CreatedDate')::timestamp + from jsonb_array_elements(comment_logs::jsonb) comment + order by (comment ->> 'CreatedDate')::timestamp desc + limit 1 + ) as last_comment_at_utc, + ( + select count(*) from jsonb_array_elements(comment_logs::jsonb) comment + ) as comment_count, + ( + select (status_step ->> 'CreatedDate')::timestamp + from jsonb_array_elements(status_history_logs::jsonb) status_step + order by (status_step ->> 'CreatedDate')::timestamp + limit 1 + ) as first_status_at_utc, + ( + select (status_step ->> 'CreatedDate')::timestamp + from jsonb_array_elements(status_history_logs::jsonb) status_step + order by (status_step ->> 'CreatedDate')::timestamp desc + limit 1 + ) as last_status_at_utc + from stg_resolutions__incidents + ), + -- The host can submit any number of damaged items in the damage report. + -- Each damaged item can have different currencies, so we need to convert + -- the amount to the host's currency. + damage_reported_items as ( + select + i.id_incident, + jsonb_array_elements(i.damage_report_items::jsonb) as item, + uh.account_currency_iso4217 as host_currency, + i.created_date_utc + from stg_resolutions__incidents i + left join int_core__user_host uh on i.id_user_host = uh.id_user_host + where i.damage_report_items is not null + ), + damage_report as ( + select + dri.id_incident, + dri.host_currency, + count(distinct dri.item ->> 'Id') as number_damaged_items, + sum( + coalesce( + ((dri.item ->> 'OriginalAmount')::numeric * cer.rate)::decimal( + 19, 4 + ), + 0 + ) + ) as original_value_amount_in_host_currency, + sum( + coalesce( + ((dri.item ->> 'OriginalAmount')::numeric * cer_gbp.rate)::decimal( + 19, 4 + ), + 0 + ) + ) as original_value_amount_in_gbp, + sum( + coalesce( + ((cm.corrective_measure ->> 'Amount')::numeric * cer.rate)::decimal( + 19, 4 + ), + 0 + ) + ) as asked_repair_amount_in_host_currency, + sum( + coalesce( + ( + (cm.corrective_measure ->> 'Amount')::numeric * cer_gbp.rate + )::decimal(19, 4), + 0 + ) + ) as asked_repair_amount_in_gbp, + sum( + coalesce( + ( + (cm.corrective_measure ->> 'SettlementAmount')::numeric + * cer.rate + )::decimal(19, 4), + 0 + ) + ) as accepted_amount_in_host_currency, + sum( + coalesce( + ( + (cm.corrective_measure ->> 'SettlementAmount')::numeric + * cer_gbp.rate + )::decimal(19, 4), + 0 + ) + ) as accepted_amount_in_gbp + from damage_reported_items dri + left join + lateral jsonb_array_elements( + case + when jsonb_typeof(dri.item -> 'CorrectiveMeasures') = 'array' + then dri.item -> 'CorrectiveMeasures' + else '[]'::jsonb + end + ) as cm(corrective_measure) + on true + left join + int_daily_currency_exchange_rates cer + on dri.created_date_utc = cer.rate_date_utc + and (cm.corrective_measure ->> 'Currency') = cer.from_currency + and dri.host_currency = cer.to_currency + left join + int_daily_currency_exchange_rates cer_gbp + on dri.created_date_utc = cer_gbp.rate_date_utc + and (cm.corrective_measure ->> 'Currency') = cer_gbp.from_currency + and cer.to_currency = 'GBP' + group by dri.id_incident, dri.host_currency + ), + guest_amounts_in_gbp as ( + select + i.id_incident, + (i.guest_contribution_amount_in_txn_currency * cer.rate)::decimal( + 19, 4 + ) as guest_contribution_amount_in_gbp + from stg_resolutions__incidents i + left join + int_daily_currency_exchange_rates cer + on (i.calculation_at_utc)::date = cer.rate_date_utc + and cer.from_currency = i.guest_contribution_currency + and cer.to_currency = 'GBP' + ) + +select + -- Basic Incident Details + i.id_incident, + i.id_verification, + i.current_status_name, + i.is_submission_complete, + i.current_agent_name, + i.document_version, + i.created_at_utc, + i.created_date_utc, + i.updated_at_utc, + i.updated_date_utc, + + -- Resolution Details + lt.first_comment_at_utc, + lt.last_comment_at_utc, + lt.comment_count, + lt.first_status_at_utc, + lt.last_status_at_utc, + case + when i.is_submission_complete + then + ( + extract(epoch from (lt.last_status_at_utc - lt.first_status_at_utc)) + / 3600 + )::decimal(19, 4) + else null + end as resolution_time_in_hours, + dr.number_damaged_items, + dr.original_value_amount_in_host_currency, + dr.original_value_amount_in_gbp, + dr.asked_repair_amount_in_host_currency, + dr.asked_repair_amount_in_gbp, + dr.accepted_amount_in_host_currency, + dr.accepted_amount_in_gbp, + dr.host_currency, + + -- Resolutions calculator + i.protection_name, + i.was_overriden, + i.waiver_or_deposit_name, + i.guest_verification_status, + i.lower_protection_limit_usd, + i.upper_protection_limit_usd, + i.calculated_payout_amount_in_txn_currency, + i.calculated_payout_currency, + i.calculated_payout_amount_in_usd, + (i.calculated_payout_amount_in_usd * cer.rate)::decimal( + 19, 4 + ) as calculated_payout_amount_in_gbp, + i.calculated_guest_charge_amount_in_txn_currency, + i.calculated_guest_charge_currency, + i.calculated_guest_charge_amount_in_usd, + (i.calculated_guest_charge_amount_in_usd * cer.rate)::decimal( + 19, 4 + ) as calculated_guest_charge_amount_in_gbp, + + -- Host Details + i.id_user_host, + i.host_account_name, + + -- Host Contact Details + i.host_email, + i.host_last_name, + i.host_first_name, + i.host_phone_code, + i.host_phone_number, + + -- Guest Details + i.id_user_guest, + i.guest_email, + i.guest_last_name, + i.guest_first_name, + i.guest_phone_code, + i.guest_phone_number, + + -- Guest Deposit Details + i.is_guest_deposit_retained, + i.is_guest_deposit_collected, + i.deposit_retained_amount_in_txn_currency, + i.deposit_retained_currency, + + -- Guest Involvements + i.has_guest_contributed_to_cost, + i.has_host_taken_preventative_steps, + i.guest_contribution_amount_in_txn_currency, + i.guest_contribution_currency, + ga.guest_contribution_amount_in_gbp, + i.is_guest_contacted_about_damage, + + -- Accommodation Details + i.id_accommodation, + i.accommodation_name, + + -- Booking Details + i.check_in_at_utc, + i.check_in_date_utc, + i.check_out_at_utc, + i.check_out_date_utc, + i.id_booking, + i.booking_status, + i.id_reservation + +from stg_resolutions__incidents i +left join logs_timeline lt on i.id_incident = lt.id_incident +left join damage_report dr on i.id_incident = dr.id_incident +left join guest_amounts_in_gbp ga on i.id_incident = ga.id_incident +left join + int_daily_currency_exchange_rates cer + on (i.calculation_at_utc)::date = cer.rate_date_utc + and cer.from_currency = 'USD' + and cer.to_currency = 'GBP' diff --git a/models/intermediate/resolutions/schema.yml b/models/intermediate/resolutions/schema.yml new file mode 100644 index 0000000..8b44fc0 --- /dev/null +++ b/models/intermediate/resolutions/schema.yml @@ -0,0 +1,422 @@ +version: 2 + +models: + - name: int_resolutions__incidents + description: | + "This table contains all incidents recorded by the resolutions team in Cosmos DB. + It includes details about the incident, the user who reported it, the associated booking, + the accommodation, the host, and the guest. Additionally, it tracks the resolution process, + including the compensation amount requested by the host, the proposed settlement calculated + by the system, and the final agreed-upon settlement amount." + columns: + - name: id_incident + data_type: text + description: "Unique identifier for the incident." + data_tests: + - not_null + - unique + + - name: id_verification + data_type: text + description: "Superhog unique validation ID, coming from other APIs." + + - name: current_status_name + data_type: text + description: "Current status of the incident." + data_tests: + - not_null + + - name: is_submission_complete + data_type: boolean + description: "Flag to indicate if the submission is complete." + + - name: current_agent_name + data_type: text + description: "Name of the agent who is currently handling the incident." + + - name: document_version + data_type: text + description: | + "Reported document source, such as ResCentre, API, or manual form." + + - name: created_at_utc + data_type: timestamp + description: "Timestamp when the incident was created." + data_tests: + - not_null + + - name: created_date_utc + data_type: date + description: "Date when the incident was created." + data_tests: + - not_null + + - name: updated_at_utc + data_type: timestamp + description: "Timestamp when the incident was last updated." + + - name: updated_date_utc + data_type: date + description: "Date when the incident was last updated." + + - name: first_comment_at_utc + data_type: timestamp + description: "Timestamp of the first comment on the incident." + + - name: last_comment_at_utc + data_type: timestamp + description: "Timestamp of the last comment on the incident." + + - name: comment_count + data_type: bigint + description: "Number of comments submitted on the incident." + + - name: first_status_at_utc + data_type: timestamp + description: "Timestamp of the first status change on the incident." + + - name: last_status_at_utc + data_type: timestamp + description: "Timestamp of the last status change on the incident." + + - name: resolution_time_in_hours + data_type: numeric + description: "Time taken to resolve the incident, in hours, if completed." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: true + + - name: number_damaged_items + data_type: bigint + description: "Number of items reported as damaged in the incident." + + - name: original_value_amount_in_host_currency + data_type: numeric + description: | + "Original value of the damaged items in the host currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: original_value_amount_in_gbp + data_type: numeric + description: | + "Original value of the damaged items in GBP." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: asked_repair_amount_in_host_currency + data_type: numeric + description: | + "Amount requested by the host for repair in the host currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: asked_repair_amount_in_gbp + data_type: numeric + description: | + "Amount requested by the host for repair in GBP." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: accepted_amount_in_host_currency + data_type: numeric + description: | + "Final accepted settlement amount in the host currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: accepted_amount_in_gbp + data_type: numeric + description: | + "Final accepted settlement amount in GBP." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: host_currency + data_type: text + description: "Host or local currency" + data_tests: + - not_null: + where: "original_value_amount_in_host_currency > 0 + or asked_repair_amount_in_host_currency > 0 + or accepted_amount_in_host_currency > 0" + + - name: was_overriden + data_type: boolean + description: | + "Flag to indicate if the proposed settlement value from the + calculator was overridden." + + - name: guest_verification_status + data_type: text + description: "Guest verification status for this booking." + + - name: lower_protection_limit_usd + data_type: numeric + description: "Lower protection limit in USD." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: upper_protection_limit_usd + data_type: numeric + description: "Upper protection limit in USD." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: calculated_payout_amount_in_txn_currency + data_type: text + description: "Calculated payout amount in local currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: calculated_payout_currency + data_type: text + description: "Currency of the calculated payout amount." + data_tests: + - not_null: + where: "calculated_payout_amount_in_txn_currency > 0" + + - name: calculated_payout_amount_in_usd + data_type: text + description: "Calculated payout amount in USD." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: calculated_payout_amount_in_gbp + data_type: text + description: "Calculated payout amount in GBP." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: calculated_guest_charge_amount_in_txn_currency + data_type: text + description: "Calculated guest charge amount in local currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: calculated_guest_charge_currency + data_type: text + description: "Currency of the calculated guest charge amount." + data_tests: + - not_null: + where: "calculated_guest_charge_amount_in_txn_currency > 0" + + - name: calculated_guest_charge_amount_in_usd + data_type: text + description: "Calculated guest charge amount in USD." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: calculated_guest_charge_amount_in_gbp + data_type: text + description: "Calculated guest charge amount in GBP." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: id_user_host + data_type: text + description: | + "Unique Id that identifies the host." + data_tests: + - not_null + - relationships: + to: ref('stg_core__user') + field: id_user + + - name: host_account_name + data_type: text + description: "Name of the host account." + + - name: host_email + data_type: text + description: "Email of the host." + + - name: host_last_name + data_type: text + description: "Last name of the host." + + - name: host_first_name + data_type: text + description: "First name of the host." + + - name: host_phone_code + data_type: text + description: "Phone code of the host." + + - name: host_phone_number + data_type: text + description: "Phone number of the host." + + - name: id_user_guest + data_type: text + description: "Superhog code that uniquely identifies a single guest." + data_tests: + - relationships: + to: ref('stg_core__user') + field: id_user + + - name: guest_email + data_type: text + description: "Email of the guest." + + - name: guest_last_name + data_type: text + description: "Last name of the guest." + + - name: guest_first_name + data_type: text + description: "First name of the guest." + + - name: guest_phone_code + data_type: text + description: "Phone code of the guest." + + - name: guest_phone_number + data_type: text + description: "Phone number of the guest." + + - name: is_guest_deposit_retained + data_type: boolean + description: "In case a deposit has been collected from the guest, + whether it has been retained or not." + + - name: is_guest_deposit_collected + data_type: boolean + description: "If the host has collected a deposit from the guest." + + - name: deposit_retained_amount_in_txn_currency + data_type: numeric + description: "Amount of the deposit retained in local currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: deposit_retained_currency + data_type: text + description: "Currency of the deposit retained." + data_tests: + - not_null: + where: "deposit_retained_amount_in_txn_currency > 0" + + - name: has_guest_contributed_to_cost + data_type: boolean + description: "If the guest has agreed to contribute to the cost + when talking to the host" + + - name: has_host_taken_preventative_steps + data_type: boolean + description: "If the host has taken any action to prevent the damage + or further damage once identified" + + - name: guest_contribution_amount_in_txn_currency + data_type: numeric + description: "Amount of the guest contribution, in case they did, + in local currency." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: guest_contribution_currency + data_type: text + description: "Currency of the guest contribution." + data_tests: + - not_null: + where: "guest_contribution_amount_in_txn_currency > 0" + + - name: guest_contribution_amount_in_gbp + data_type: numeric + description: "Amount of the guest contribution, in case they did, + in GBP." + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: is_guest_contacted_about_damage + data_type: boolean + description: "If the host has contacted the guest about the damage caused" + + - name: id_accommodation + data_type: numeric + description: "Superhog code that uniquely identifies a single accommodation." + data_tests: + - not_null + - relationships: + to: ref('stg_core__accommodation') + field: id_accommodation + + - name: accommodation_name + data_type: text + description: "Accommodation name." + + - name: check_in_at_utc + data_type: timestamp without time zone + description: "Timestamp of the check-in date in UTC of the booking." + data_tests: + - not_null + + - name: check_in_date_utc + data_type: date + description: "Date of the check-in date in UTC of the booking." + data_tests: + - not_null + + - name: check_out_at_utc + data_type: timestamp without time zone + description: "Timestamp of the check-out date in UTC of the booking." + data_tests: + - not_null + + - name: check_out_date_utc + data_type: date + description: "Date of the check-out date in UTC of the booking." + data_tests: + - not_null + + - name: id_booking + data_type: numeric + description: "Superhog unique booking ID" + data_tests: + - not_null + - relationships: + to: ref('stg_core__booking') + field: id_booking + + - name: booking_status + data_type: text + description: "Status of the booking." + + - name: id_reservation + data_type: text + description: "External unique ID for the reservation." diff --git a/models/staging/resolutions/schema.yml b/models/staging/resolutions/schema.yml index 3ef367f..fcf6233 100644 --- a/models/staging/resolutions/schema.yml +++ b/models/staging/resolutions/schema.yml @@ -301,6 +301,13 @@ models: data_type: text description: "List of items that were damaged." + - name: calculation_at_utc + data_type: timestamp without time zone + description: "Timestamp of the calculation." + data_tests: + - not_null: + where: "calculated_payout_amount_in_txn_currency > 0" + - name: protection_name data_type: text description: "Indicates the selected booking protection plan, diff --git a/models/staging/resolutions/stg_resolutions__incidents.sql b/models/staging/resolutions/stg_resolutions__incidents.sql index 7adb483..3e2324c 100644 --- a/models/staging/resolutions/stg_resolutions__incidents.sql +++ b/models/staging/resolutions/stg_resolutions__incidents.sql @@ -194,6 +194,9 @@ select -- Calculator {{ adapter.quote("documents") }} -> 'SavedCalculation' + ->> 'CalculationDate' as calculation_at_utc, + {{ adapter.quote("documents") }} + -> 'SavedCalculation' ->> 'ProtectionName' as protection_name, ({{ adapter.quote("documents") }} -> 'SavedCalculation' ->> 'WasOverriden')::boolean as was_overriden,