From d08adfd2c05a321ba6eb2c1133dfe514cf84854d Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Wed, 24 Jul 2024 16:53:16 +0200 Subject: [PATCH 1/2] Created new model with listings with check in hero active --- .../int_core__check_in_cover_listings.sql | 40 +++++++ models/intermediate/core/schema.yaml | 100 +++++++++++++++++- 2 files changed, 139 insertions(+), 1 deletion(-) create mode 100644 models/intermediate/core/int_core__check_in_cover_listings.sql diff --git a/models/intermediate/core/int_core__check_in_cover_listings.sql b/models/intermediate/core/int_core__check_in_cover_listings.sql new file mode 100644 index 0000000..49974a9 --- /dev/null +++ b/models/intermediate/core/int_core__check_in_cover_listings.sql @@ -0,0 +1,40 @@ +with + int_core__check_in_cover_users as ( + select * from {{ ref("int_core__check_in_cover_users") }} + ), + int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}), + int_core__vr_check_in_cover as ( + select * from {{ ref("int_core__vr_check_in_cover") }} + ), + check_in_cover_purchased as ( + select + cic.id_accommodation, + count(cic.id_verification_request) as check_in_cover_purchased + from int_core__vr_check_in_cover cic + where cover_was_purchased is true + group by cic.id_accommodation + ) +select + cicu.id_user_host, + cicu.id_deal, + cicu.last_name, + cicu.user_name, + cicu.first_name, + cicu.host_email, + cicu.phone_number, + cicu.joined_at_utc, + cicu.joined_date_utc, + cicu.check_in_cover_added_date_utc, + cicu.billing_town, + cicu.company_name, + a.id_accommodation, + a.is_active, + a.friendly_name, + a.country_name, + a.town, + a.postcode, + a.address_line_1, + cicp.check_in_cover_purchased +from int_core__check_in_cover_users cicu +left join int_core__accommodation a on a.id_user_host = cicu.id_user_host +left join check_in_cover_purchased cicp on a.id_accommodation = cicp.id_accommodation diff --git a/models/intermediate/core/schema.yaml b/models/intermediate/core/schema.yaml index f9da3a2..61fcb64 100644 --- a/models/intermediate/core/schema.yaml +++ b/models/intermediate/core/schema.yaml @@ -1379,4 +1379,102 @@ models: - name: dwh_extracted_at_utc data_type: timestamp with time zone - description: "" \ No newline at end of file + description: "" + + - name: int_core__check_in_cover_listings + description: + This model contains information about hosts and their listings + that offer check in cover. + It has basic information on the users and listings like country, + town, address and if they are active or not. + + This model is restricted to active user so it doesn't include historical + data like users that had check-in cover but are currently inactive. + columns: + - name: id_user_host + data_type: character varying + description: Unique id value for the user + tests: + - not_null + + - name: id_deal + data_type: character varying + description: "" + + - name: last_name + data_type: character varying + description: Last name of the user + + - name: user_name + data_type: character varying + description: User name of the user + + - name: first_name + data_type: character varying + description: First name of the user + + - name: host_email + data_type: character varying + description: Email of the user + + - name: phone_number + data_type: character varying + description: Phone number of the user + + - name: joined_at_utc + data_type: timestamp without time zone + description: Date and time the user joined + + - name: joined_date_utc + data_type: date + description: Date the user joined + + - name: check_in_cover_added_date_utc + data_type: date + description: + Date the user first included check-in cover + + - name: billing_town + data_type: character varying + description: "" + + - name: company_name + data_type: character varying + description: "" + + - name: id_accommodation + data_type: bigint + description: "Id of the accommodation or listing. It's the unique key for this model." + tests: + - not_null + - unique + + - name: is_active + data_type: boolean + description: "Boolean to indicate if the accommodation is active or not" + + - name: friendly_name + data_type: character varying + description: "Name of the accommodation" + + - name: country_name + data_type: character varying + description: "Name of the country where the accommodation is located." + + - name: town + data_type: character varying + description: "Town in which the accommodation is located" + + - name: postcode + data_type: character varying + description: "" + + - name: address_line_1 + data_type: character varying + description: "" + + - name: check_in_cover_purchased + data_type: bigint + description: + "Count of how many Check-in covers have been + purchased for this accommodation" \ No newline at end of file From e2fb73d5583326cce16685548f82ecc7c6d723f1 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Wed, 24 Jul 2024 17:31:25 +0200 Subject: [PATCH 2/2] Added count distinct --- models/intermediate/core/int_core__check_in_cover_listings.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/models/intermediate/core/int_core__check_in_cover_listings.sql b/models/intermediate/core/int_core__check_in_cover_listings.sql index 49974a9..5f12fbc 100644 --- a/models/intermediate/core/int_core__check_in_cover_listings.sql +++ b/models/intermediate/core/int_core__check_in_cover_listings.sql @@ -9,7 +9,7 @@ with check_in_cover_purchased as ( select cic.id_accommodation, - count(cic.id_verification_request) as check_in_cover_purchased + count(distinct cic.id_verification_request) as check_in_cover_purchased from int_core__vr_check_in_cover cic where cover_was_purchased is true group by cic.id_accommodation