New PMS model
This commit is contained in:
parent
073620bd3d
commit
74b045a930
4 changed files with 232 additions and 0 deletions
|
|
@ -0,0 +1,55 @@
|
||||||
|
with
|
||||||
|
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
|
||||||
|
int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}),
|
||||||
|
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
|
||||||
|
stg_core__integration as (select * from {{ ref("stg_core__integration") }}),
|
||||||
|
stg_core__integration_type as (
|
||||||
|
select * from {{ ref("stg_core__integration_type") }}
|
||||||
|
),
|
||||||
|
booking_integrations as (
|
||||||
|
select
|
||||||
|
it.display_name,
|
||||||
|
b.id_user_host,
|
||||||
|
count(distinct b.id_booking) as booking_count
|
||||||
|
from int_core__bookings b
|
||||||
|
inner join
|
||||||
|
stg_core__integration i
|
||||||
|
on b.id_user_host = i.id_superhog_user
|
||||||
|
and b.created_at_utc between i.created_at_utc and coalesce(
|
||||||
|
i.deleted_at_utc, {{ var("end_of_time") }}
|
||||||
|
)
|
||||||
|
inner join
|
||||||
|
stg_core__integration_type it
|
||||||
|
on it.id_integration_type = i.id_integration_type
|
||||||
|
where
|
||||||
|
b.verification_request_booking_source = 'PMS'
|
||||||
|
and b.is_duplicate_booking = false
|
||||||
|
group by 1, 2
|
||||||
|
)
|
||||||
|
select
|
||||||
|
bi.display_name as pms_name,
|
||||||
|
uh.id_user_host,
|
||||||
|
uh.id_deal,
|
||||||
|
uh.account_type,
|
||||||
|
uh.first_name,
|
||||||
|
uh.last_name,
|
||||||
|
uh.company_name,
|
||||||
|
uh.email,
|
||||||
|
uh.billing_country_name,
|
||||||
|
uh.billing_country_iso_3,
|
||||||
|
uh.joined_date_utc,
|
||||||
|
bi.booking_count,
|
||||||
|
count(distinct a.id_accommodation) as accommodation_count
|
||||||
|
from int_core__user_host uh
|
||||||
|
inner join stg_core__integration i on i.id_superhog_user = uh.id_user_host
|
||||||
|
inner join
|
||||||
|
stg_core__integration_type it
|
||||||
|
on i.id_integration_type = it.id_integration_type
|
||||||
|
and i.is_active = true
|
||||||
|
left join int_core__accommodation a on a.id_user_host = uh.id_user_host and a.is_active
|
||||||
|
left join
|
||||||
|
booking_integrations bi
|
||||||
|
on bi.id_user_host = uh.id_user_host
|
||||||
|
and bi.display_name = it.display_name
|
||||||
|
where uh.is_test_account = false
|
||||||
|
group by 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12
|
||||||
|
|
@ -5739,3 +5739,82 @@ models:
|
||||||
data_type: bigint
|
data_type: bigint
|
||||||
description: |
|
description: |
|
||||||
The total number of user hosts that have appeared in New Dash for this deal.
|
The total number of user hosts that have appeared in New Dash for this deal.
|
||||||
|
|
||||||
|
- name: int_core__property_managers_system
|
||||||
|
description: |
|
||||||
|
This model contains information about active property managers systems (PMS)
|
||||||
|
and their associated hosts.
|
||||||
|
It includes details about the host, their account type, company,
|
||||||
|
billing information, and the number of accommodations they manage.
|
||||||
|
columns:
|
||||||
|
- name: pms_name
|
||||||
|
data_type: text
|
||||||
|
description: |
|
||||||
|
The name of the property management system.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_user_host
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
The unique ID for the host. Can be null.
|
||||||
|
|
||||||
|
- name: id_deal
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Main identifier of the B2B clients. A Deal can have multiple Hosts.
|
||||||
|
A Host can have only 1 Deal or no Deal at all. This field can be null.
|
||||||
|
|
||||||
|
- name: account_type
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Name of the account type. Can be null and might be not up-to-date.
|
||||||
|
|
||||||
|
- name: first_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
First name of the Host.
|
||||||
|
|
||||||
|
- name: last_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Last name of the Host.
|
||||||
|
|
||||||
|
- name: company_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Name of the company. In some cases, it's the same as the first_name,
|
||||||
|
the last_name, a concatenation of both, or something different.
|
||||||
|
Can be null and empty.
|
||||||
|
|
||||||
|
- name: email
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Email of the Host.
|
||||||
|
|
||||||
|
- name: billing_country_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Name of the country in which the Host is billed.
|
||||||
|
In some cases it's null.
|
||||||
|
|
||||||
|
- name: billing_country_iso_3
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
ISO 3166-1 alpha-3 country code in which the Host is billed.
|
||||||
|
In some cases it's null.
|
||||||
|
|
||||||
|
- name: joined_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date of when the Host user joined Superhog.
|
||||||
|
|
||||||
|
- name: booking_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
The number of bookings from the host made through the PMS.
|
||||||
|
|
||||||
|
- name: accommodation_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
The number of accommodations managed by the host.
|
||||||
|
|
|
||||||
19
models/reporting/core/core__property_managers_system.sql
Normal file
19
models/reporting/core/core__property_managers_system.sql
Normal file
|
|
@ -0,0 +1,19 @@
|
||||||
|
with
|
||||||
|
int_core__property_managers_system as (
|
||||||
|
select * from {{ ref("int_core__property_managers_system") }}
|
||||||
|
)
|
||||||
|
select
|
||||||
|
pms_name as pms_name,
|
||||||
|
id_user_host as id_user_host,
|
||||||
|
id_deal as id_deal,
|
||||||
|
account_type as account_type,
|
||||||
|
first_name as first_name,
|
||||||
|
last_name as last_name,
|
||||||
|
company_name as company_name,
|
||||||
|
email as email,
|
||||||
|
billing_country_name as billing_country_name,
|
||||||
|
billing_country_iso_3 as billing_country_iso_3,
|
||||||
|
joined_date_utc as joined_date_utc,
|
||||||
|
booking_count as booking_count,
|
||||||
|
accommodation_count as accommodation_count
|
||||||
|
from int_core__property_managers_system
|
||||||
|
|
@ -1920,3 +1920,82 @@ models:
|
||||||
description: |
|
description: |
|
||||||
The currency in which the host receives their payment (may differ from
|
The currency in which the host receives their payment (may differ from
|
||||||
the transaction currency).
|
the transaction currency).
|
||||||
|
|
||||||
|
- name: core__property_managers_system
|
||||||
|
description: |
|
||||||
|
This model contains information about active property managers systems (PMS)
|
||||||
|
and their associated hosts.
|
||||||
|
It includes details about the host, their account type, company,
|
||||||
|
billing information, and the number of accommodations they manage.
|
||||||
|
columns:
|
||||||
|
- name: pms_name
|
||||||
|
data_type: text
|
||||||
|
description: |
|
||||||
|
The name of the property management system.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_user_host
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
The unique ID for the host. Can be null.
|
||||||
|
|
||||||
|
- name: id_deal
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Main identifier of the B2B clients. A Deal can have multiple Hosts.
|
||||||
|
A Host can have only 1 Deal or no Deal at all. This field can be null.
|
||||||
|
|
||||||
|
- name: account_type
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Name of the account type. Can be null and might be not up-to-date.
|
||||||
|
|
||||||
|
- name: first_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
First name of the Host.
|
||||||
|
|
||||||
|
- name: last_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Last name of the Host.
|
||||||
|
|
||||||
|
- name: company_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Name of the company. In some cases, it's the same as the first_name,
|
||||||
|
the last_name, a concatenation of both, or something different.
|
||||||
|
Can be null and empty.
|
||||||
|
|
||||||
|
- name: email
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Email of the Host.
|
||||||
|
|
||||||
|
- name: billing_country_name
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Name of the country in which the Host is billed.
|
||||||
|
In some cases it's null.
|
||||||
|
|
||||||
|
- name: billing_country_iso_3
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
ISO 3166-1 alpha-3 country code in which the Host is billed.
|
||||||
|
In some cases it's null.
|
||||||
|
|
||||||
|
- name: joined_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date of when the Host user joined Superhog.
|
||||||
|
|
||||||
|
- name: booking_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
The number of bookings from the host made through the PMS.
|
||||||
|
|
||||||
|
- name: accommodation_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
The number of accommodations managed by the host.
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue