diff --git a/definitions/staging/stg_AGENT.sqlx b/definitions/staging/stg_AGENT.sqlx index 666bedb..9071106 100644 --- a/definitions/staging/stg_AGENT.sqlx +++ b/definitions/staging/stg_AGENT.sqlx @@ -11,10 +11,37 @@ config { /* Originally AGENT_NAME field contains both name and languages of the agent. -They can be divined by different variations of signs. Next 2 subqueries extract AGENT_NAME and LANGUAGES +They can be divined by different variations of signs. Next 3 subqueries extract AGENT_NAME and LANGUAGES into 2 different fields for calls and digital data. */ -with agent_digital as ( +with agent_status as ( + select AGENT_ID, + case + when strpos(AGENT_NAME, '(') > 0 and strpos(AGENT_NAME, ') ') = 0 + then left(agent_name, strpos(AGENT_NAME, '(')-1) + when strpos(AGENT_NAME, ' -') > 0 + then left(agent_name, strpos(AGENT_NAME, ' -')-1) + when strpos(AGENT_NAME, '-') > 0 + then left(agent_name, strpos(AGENT_NAME, '-')-1) + else AGENT_NAME + end AGENT_NAME, + AGENT_GROUP, + case + when strpos(AGENT_NAME, '-- ') > 0 + then upper(substr(AGENT_NAME, strpos(AGENT_NAME, '--') + 3)) + when strpos(AGENT_NAME, '--') > 0 + then upper(substr(AGENT_NAME, strpos(AGENT_NAME, '--') + 2)) + when strpos(AGENT_NAME, '- ') > 0 + then upper(substr(AGENT_NAME, strpos(AGENT_NAME, '-') + 2)) + when strpos(AGENT_NAME, '-') > 0 + then upper(substr(AGENT_NAME, strpos(AGENT_NAME, '-') + 1)) + else null + end AS LANGUAGES, + TIMESTAMP + from `pphe_five9_stg.stg_agent_status` + where AGENT_NAME is not null -- there are some dummy records with nulls in every other agent field +), +agent_digital as ( select AGENT_ID, case when strpos(AGENT_NAME, '(') > 0 and strpos(AGENT_NAME, ') ') = 0 @@ -71,6 +98,8 @@ all_agents as ( select * from agent_digital union distinct select * from agent_calls + union distinct + select * from agent_status ), -- Deduplication by AGENT_ID and Timestamp. It is necessary because agent characteristics can change over time all_agents_dedup as(