config { type: "table", schema: "pphe_five9_gold", uniqueKey: ["AGENT_ID", "TIMESTAMP", "STATE"], assertions: { uniqueKey: ["AGENT_ID", "TIMESTAMP", "STATE"], nonNull: ["AGENT_ID", "TIMESTAMP", "STATE"], rowConditions: [ 'STATE_GROUP <> "NOT_MAPPED"', 'PRODUCTIVE <> "NOT_MAPPED"', 'REVENUE <> "NOT_MAPPED"', 'AGENT_ID = "0" or (AGENT_ID <> "0" AND AGENT_NAME <> "NOT_MAPPED")', 'STATE_ID <> 0', 'REASON_CODE is null or (REASON_CODE is not null and REASON_CODE_ID <> 0)' ] }, tags: ["agent_status_report"], description: "Exporting last 7 days of AGENT_STATUS table." } --Extraction and transformation of fields that are used in Board load further. Contains last 7 days select ags.AGENT_ID, COALESCE(a.AGENT_NAME, 'NOT_MAPPED') AGENT_NAME, COALESCE(a.AGENT_GROUP, 'NOT_MAPPED') as AGENT_GROUP, COALESCE(a.AGENT_GROUP_ID, 0) as AGENT_GROUP_ID, COALESCE(a.LANGUAGES, 'NOT_MAPPED') as LANGUAGES, COALESCE(a.CODE, 'NOT_MAPPED') as LANG_CODE, ags.AGENT_STATE_TIME, regexp_replace( cast(time(timestamp_seconds(cast(ags.AGENT_STATE_TIME as int))) as string), r'^\d\d', cast(extract(hour from time(timestamp_seconds(cast(ags.AGENT_STATE_TIME as int)))) + 24 * unix_date(date(timestamp_seconds(cast(ags.AGENT_STATE_TIME as int)))) as string) ) as AGENT_STATE_TIME_FORMATTED, ags.AGENT_START_DATE, ags.REASON_CODE, COALESCE(mrc.REASON_CODE_ID, 0) as REASON_CODE_ID, ags.TIMESTAMP, date(ags.TIMESTAMP) DATE, EXTRACT(HOUR FROM ags.TIMESTAMP) HOUR, EXTRACT(MONTH FROM ags.TIMESTAMP) MONTH, EXTRACT(YEAR FROM ags.TIMESTAMP) YEAR, ags.AGENT_STATES, ags.MEDIA_AVAILABILITY, ags.UNAVAILABLE_FOR_CALLS, ags.AVAILABLE_FOR_ALL, ags.UNAVAILABLE_FOR_VM, ags.AVAILABLE_FOR_CALLS, ags.SKILL_AVAILABILITY, ags.AVAILABLE_FOR_VM, ags.STATE, COALESCE(mas.STATE_ID, 0) as STATE_ID, COALESCE(masg.STATE_GROUP_ID, 0) as STATE_GROUP_ID, COALESCE(masg.STATE_GROUP, 'NOT_MAPPED') as STATE_GROUP, ags.UNPAID_TIME, regexp_replace( cast(time(timestamp_seconds(cast(ags.UNPAID_TIME as int))) as string), r'^\d\d', cast(extract(hour from time(timestamp_seconds(cast(ags.UNPAID_TIME as int)))) + 24 * unix_date(date(timestamp_seconds(cast(ags.UNPAID_TIME as int)))) as string) ) as UNPAID_TIME_FORMATTED, ags.PAID_TIME, regexp_replace( cast(time(timestamp_seconds(cast(ags.PAID_TIME as int))) as string), r'^\d\d', cast(extract(hour from time(timestamp_seconds(cast(ags.PAID_TIME as int)))) + 24 * unix_date(date(timestamp_seconds(cast(ags.PAID_TIME as int)))) as string) ) as PAID_TIME_FORMATTED, COALESCE(mpr.PRODUCTIVE, 'NOT_MAPPED') as PRODUCTIVE, COALESCE(mpr.REVENUE, 'NOT_MAPPED') as REVENUE, from ${ref("stg_agent_status")} ags left join ${ref("stg_AGENT")} a on ags.AGENT_ID = a.AGENT_ID left join ${ref("MAPPING_AGENT_STATE_ID")} mas on ags.STATE = mas.STATE left join ${ref("MAPPING_AGENT_STATE_GROUP")} masgi on mas.STATE_ID = masgi.STATE_ID left join ${ref("MAPPING_AGENT_STATE_GROUP_ID")} masg on masgi.STATE_GROUP_ID = masg.STATE_GROUP_ID left join ${ref("MAPPING_AGENT_REASON_CODE_ID")} mrc on ags.REASON_CODE = mrc.REASON_CODE left join ${ref("MAPPING_PRODUCTIVE_REVENUE")} mpr on COALESCE(mas.STATE_ID, 0) = COALESCE(mpr.STATE_ID, 0) and COALESCE(mrc.REASON_CODE_ID, 0) = COALESCE(mpr.REASON_CODE_ID, 0) where date(ags.TIMESTAMP) >= DATE_SUB(CURRENT_DATE(), INTERVAL 7 DAY) and ags.STATE not in ('Login', 'Logout', 'On Park', 'On Preview', 'On Video', 'On Voicemail') and ags.AGENT_ID <> '400000000081027' and date(ags.TIMESTAMP) < CURRENT_DATE()