Merged PR 2516: Create host_user and user_role in intermediate

# Description

Adds 2 new tables:
- `int_core__user_role`: contains the relationship of a given user has a role.
- `int_core__user_host`: based on the previous table, it selects the users and main information from those users that are considered as hosts according to the role they have.

Note: I needed to change the test in stg. A user, generally, can have no role, one role, or multiple roles. Thus we cannot propagate this information in the unified_user model.

# Checklist

- [X] The edited models and dependants run properly with production data.
- [X] The edited models are sufficiently documented.
- [X] The edited models contain PK tests, and I've ran and passed them.
- [X] I have checked for DRY opportunities with other models and docs.
- [X] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Related work items: #19513
This commit is contained in:
Oriol Roqué Paniagua 2024-08-07 14:28:34 +00:00
parent ad7d94b604
commit 7177b41e19
4 changed files with 165 additions and 3 deletions

View file

@ -0,0 +1,31 @@
{% set host_roles = "('EDEPOSIT', 'HOST', 'KNOWYOURGUEST', 'PLATFORM', 'PROPERTYVERIFICATIONMANAGER', 'SCREENINGAPI')" %}
{{ config(materialized="table", unique_key="id_user_host") }}
with
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
int_core__user_role as (select * from {{ ref("int_core__user_role") }}),
-- A USER CAN HAVE MULTIPLE ROLES, THUS DISTINCT IS NEEDED TO AVOID DUPLICATES
users_with_host_roles as (
select distinct id_user
from int_core__user_role
where upper(role_name) in {{ host_roles }}
)
select
uu.id_user as id_user_host,
uu.id_account_type,
uu.id_billing_country,
uu.account_currency_iso4217,
uu.user_code,
uu.first_name,
uu.last_name,
uu.company_name,
uu.email,
uu.id_deal,
uu.joined_at_utc,
uu.joined_date_utc,
uu.created_date_utc,
uu.updated_date_utc
from int_core__unified_user uu
inner join users_with_host_roles hr on uu.id_user = hr.id_user

View file

@ -0,0 +1,7 @@
with
stg_core__user_role as (select * from {{ ref("stg_core__user_role") }}),
stg_core__role as (select * from {{ ref("stg_core__role") }})
select distinct id_user, role_name
from stg_core__user_role ur
inner join staging.stg_core__role r on ur.id_role = r.id_role

View file

@ -1666,4 +1666,130 @@ models:
The date in which the booking should be invoiced.
This could be the check-in date of the booking or the date in which the guest verification
started, depending on the billing settings of the host.
started, depending on the billing settings of the host.
- name: int_core__user_role
description: |
This model contains the relationship of user has a role.
A User in this table can have 1 or more than 1 roles.
Not all Users in this table appear in the standard user table,
meaning that not all users have a role assigned.
The possible roles are:
- Host
- Platform
- EDeposit
- Guest
- Admin
- KnowYourGuest
- ScreeningAPI
- PropertyVerificationManager
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- id_user
- role_name
columns:
- name: id_user
data_type: string
description: |
The identifier of the user. Can be duplicated if it has multiple roles.
tests:
- not_null
- name: role_name
data_type: string
description: The name of the role a user has.
tests:
- accepted_values:
values:
- Host
- Platform
- EDeposit
- Guest
- Admin
- KnowYourGuest
- ScreeningApi
- PropertyVerificationManager
- name: int_core__user_host
description: |
This table provides information of the users that act as Hosts.
A Host needs to be understood in the broad sense of the term. Here host means any
user that acts as a "B2B" client.
The categorisation as a Host is based on the role of the user. Any user that has
any of the following roles will be considered as a Host in this table:
- Host
- Platform
- EDeposit
- KnowYourGuest
- ScreeningAPI
- PropertyVerificationManager
columns:
- name: id_user_host
data_type: character varying
description: The unique user ID for the Host.
tests:
- not_null
- unique
- name: id_account_type
data_type: integer
description: |
Account type ID. Can be null and might be not up-to-date.
- name: id_billing_country
data_type: integer
description: |
ID of the country in which the Host is billed.
In some cases it's null.
- name: account_currency_iso4217
data_type: string
description: |
3 character currency code linked to the account.
In some cases it's null.
- name: user_code
data_type: integer
description: |
A code identifying users.
- name: first_name
data_type: string
description: |
First name of the Host.
- name: last_name
data_type: string
description: |
Last name of the Host.
- name: company_name
data_type: string
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: string
description: |
Electronic mail of the Host.
- name: id_deal
data_type: string
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: joined_at_utc
data_type: timestamp
description: |
Timestamp of when the Host user joined Superhog.
- name: joined_date_utc
data_type: date
description: |
Date of when the Host user joined Superhog.
- name: created_date_utc
data_type: date
description: |
Date of when the Host user was created in our systems.
- name: updated_date_utc
data_type: date
description: |
Date of the last time the information of the Host was updated
in our systems.

View file

@ -150,9 +150,7 @@ models:
columns:
- name: id_role
tests:
- unique
- not_null
- name: id_user
tests:
- unique
- not_null