From cd9cba85898d745751e365282da4303eaa46d553 Mon Sep 17 00:00:00 2001 From: "douglas.strappasson" Date: Mon, 25 Sep 2023 13:49:17 -0400 Subject: [PATCH] ajuste no script SQL, para otimizar o tempo de retorno da consulta --- .../callcenter/geral/desempenhoOperacao.php | 207 +++++++++++++----- 1 file changed, 149 insertions(+), 58 deletions(-) diff --git a/relatorios/callcenter/geral/desempenhoOperacao.php b/relatorios/callcenter/geral/desempenhoOperacao.php index aed231cd..1be0283c 100644 --- a/relatorios/callcenter/geral/desempenhoOperacao.php +++ b/relatorios/callcenter/geral/desempenhoOperacao.php @@ -103,65 +103,156 @@ $fimMes = "$ano-$mes-" . GetLastDayofMonth($ano, $mes); $dac = $this->___dac; - $query = "SELECT FILA, date_part('day',DATA) AS DATA - ,OFERECIDAS - ,ATENDIDAS_URA - ,ABANDONADAS - ,ATENDIDAS_FILA - ,ATENDIDAS_PA - ,ORIGINADAS_PA - ,ATENDIDAS_30 - ,TRANSFERIDAS - ,ESPERA - ,round( CASE WHEN(ESPERA = 0)THEN 0 ELSE (TEMPO_ESPERA / ESPERA) END ) * INTERVAL '1 SECOND' AS TME - ,round( CASE WHEN(ATENDIDAS_PA = 0)THEN 0 ELSE (TEMPO_ATENDIMENTO / ATENDIDAS_PA)END) * INTERVAL '1 SECOND' AS TMA - ,round(CASE WHEN(ABANDONADAS = 0)THEN 0 ELSE (TEMPO_ABANDONO / ABANDONADAS) END) * INTERVAL '1 SECOND' AS TMAB - ,(CASE WHEN((ATENDIDAS_PA::FLOAT + ABANDONADAS::FLOAT ) = 0)THEN 0 ELSE ATENDIDAS_30::FLOAT / (ATENDIDAS_PA::FLOAT + ABANDONADAS::FLOAT ) END * 100)::numeric(5,2) as INB - ,(CASE WHEN(OFERECIDAS::FLOAT = 0)THEN 0 ELSE (ABANDONADAS::FLOAT / OFERECIDAS::FLOAT) END * 100)::numeric(5,2) as IAB - ,TEMPO_ESPERA - ,TEMPO_ATENDIMENTO - ,TEMPO_ORIGINADAS - ,TEMPO_ABANDONO - ,TRANSBORDADA - ,TRANSBORDANDO - FROM ( + $query = "WITH DADOS_BRUTOS AS ( + SELECT + a.data_bilhete AS DATA, + a.data_bilhete, + b.fila, + CASE + WHEN ( + EXISTS ( + SELECT '' + FROM pbx_bilhetes + WHERE data_bilhete = a.data_bilhete + AND accountcode = a.uniqueid + AND evento IN ('COMPLETEAGENT', 'COMPLETECALLER', 'COMPLETAAGENT', 'COMPLETACALLER') + ) + ) THEN + CASE + WHEN (b.evento IN ('COMPLETEAGENT', 'COMPLETECALLER')) THEN 'TRANSFER' + ELSE 'TRANSFERORIG' + END + ELSE b.evento + END AS evento, + CASE + WHEN ( + b.evento = 'TRANSBORDADO' + OR ( + (b.evento = 'ENTERQUEUE') + AND EXISTS ( + SELECT '' + FROM ast_eventos_dacs + WHERE uid2 = b.uid2 + AND fila <> b.fila + AND evento = 'EXITWITHTIMEOUT' + AND b.id > id + ) + ) + ) THEN 1 + ELSE 0 + END AS transbordada, + b.param1, + b.param2, + b.param3, + b.param4, + b.agente, + ( + SELECT COUNT(*) + FROM pbx_bilhetes_complemento + WHERE uniqueid2 = a.uniqueid + AND direcao = 'ura' + ) AS ura, + a.uniqueid + FROM pbx_eventos_dacs b + INNER JOIN pbx_bilhetes a ON a.uniqueid = b.uid2 + AND a.lastapp <> 'Transferred Call' + INNER JOIN pbx_dacs d ON d.nome = b.fila + WHERE b.evento IN ( + 'ABANDON', 'COMPLETEAGENT', 'COMPLETECALLER', 'COMPLETAAGENT', 'COMPLETACALLER', + 'CONNECT', 'ENTERQUEUE', 'TRANSFER', 'TRANSFERORIG', 'EXITWITHTIMEOUT', 'TRANSBORDANDO', + 'TRANSBORDADO', 'BUSYS', 'NOANSWERS' + ) + AND a.data_bilhete >= '$iniMes' + AND a.data_bilhete <= '$fimMes' + AND d.id = '$dac' + AND ( + 1 = CASE + WHEN (b.evento = 'ABANDON') THEN + CASE + WHEN ( + NOT EXISTS ( + SELECT '' + FROM ast_eventos_dacs + WHERE uid2 = b.uid2 + AND evento = 'TRANSBORDANDO' + AND fila = b.fila + ) + ) THEN 1 + ELSE 0 + END + ELSE 1 + END + ) + ), + DADOS_INTERMEDIARIOS AS ( + SELECT + FILA, + DATE_PART('day', DATA) AS DATA, + SUM(CASE WHEN EVENTO IN ('ABANDON', 'COMPLETEAGENT', 'COMPLETECALLER', 'TRANSFER', 'TRANSBORDANDO') THEN 1 ELSE 0 END) AS OFERECIDAS, + SUM(CASE WHEN (EVENTO = 'ENTERQUEUE') AND (URA > 0) THEN 1 ELSE 0 END) AS ATENDIDAS_URA, + SUM(CASE WHEN EVENTO = 'ABANDON' THEN 1 ELSE 0 END) AS ABANDONADAS, + SUM(CASE WHEN EVENTO IN ('COMPLETEAGENT', 'COMPLETECALLER', 'TRANSFER') AND SUBSTRING(AGENTE, 1, 5) <> 'Agent' THEN 1 ELSE 0 END) AS ATENDIDAS_FILA, + SUM(CASE WHEN EVENTO IN ('COMPLETEAGENT', 'COMPLETECALLER', 'TRANSFER') AND SUBSTRING(AGENTE, 1, 5) = 'Agent' THEN 1 ELSE 0 END) AS ATENDIDAS_PA, + SUM(CASE WHEN EVENTO IN ('COMPLETAAGENT', 'COMPLETACALLER', 'TRANSFERORIG', 'BUSYS', 'NOANSWERS') THEN 1 ELSE 0 END) AS ORIGINADAS_PA, + SUM(CASE WHEN EVENTO IN ('COMPLETEAGENT', 'COMPLETECALLER', 'TRANSFER') AND STRTOINT(PARAM1) <= '30' AND SUBSTRING(AGENTE, 1, 5) = 'Agent' THEN 1 ELSE 0 END) AS ATENDIDAS_30, + SUM(CASE WHEN (EVENTO = 'TRANSFER') OR (EXISTS(SELECT '' FROM pbx_bilhetes WHERE data_bilhete = DADOS_BRUTOS.data_bilhete AND accountcode = DADOS_BRUTOS.uniqueid AND EVENTO IN ('COMPLETEAGENT', 'COMPLETECALLER'))) THEN 1 ELSE 0 END) AS TRANSFERIDAS, + SUM(CASE WHEN EVENTO IN ('CONNECT') AND STRTOINT(PARAM1) > '3' THEN 1 ELSE 0 END) AS ESPERA, + SUM(CASE WHEN EVENTO IN ('CONNECT') AND STRTOINT(PARAM1) > '3' THEN STRTOINT(PARAM1) ELSE 0 END) AS TEMPO_ESPERA, + SUM(CASE WHEN EVENTO IN ('COMPLETEAGENT', 'COMPLETECALLER') AND STRTOINT((CASE WHEN (COALESCE(PARAM2, '') = '') THEN '0' ELSE PARAM2 END)) > '1' THEN STRTOINT(PARAM2) ELSE 0 END) AS TEMPO_ATENDIMENTO, + SUM(CASE WHEN EVENTO IN ('COMPLETAAGENT', 'COMPLETACALLER') AND STRTOINT((CASE WHEN (COALESCE(PARAM2, '') = '') THEN '0' ELSE PARAM2 END)) > '1' THEN STRTOINT(PARAM2) ELSE 0 END) AS TEMPO_ORIGINADAS, + SUM(CASE WHEN EVENTO = 'ABANDON' THEN (CASE WHEN (COALESCE(PARAM3, '') = '') THEN 0 ELSE PARAM3::INT END) ELSE 0 END) AS TEMPO_ABANDONO, + SUM(CASE WHEN EVENTO IN ('EXITWITHTIMEOUT', 'TRANSBORDANDO') THEN 1 ELSE 0 END) AS TRANSBORDANDO, + SUM(transbordada) AS TRANSBORDADA + FROM DADOS_BRUTOS + GROUP BY FILA, DATA + ), + AGREGADOS AS ( + SELECT + FILA, + DATA, + SUM(OFERECIDAS) AS OFERECIDAS, + SUM(ATENDIDAS_URA) AS ATENDIDAS_URA, + SUM(ABANDONADAS) AS ABANDONADAS, + SUM(ATENDIDAS_FILA) AS ATENDIDAS_FILA, + SUM(ATENDIDAS_PA) AS ATENDIDAS_PA, + SUM(ORIGINADAS_PA) AS ORIGINADAS_PA, + SUM(ATENDIDAS_30) AS ATENDIDAS_30, + SUM(TRANSFERIDAS) AS TRANSFERIDAS, + SUM(ESPERA) AS ESPERA, + SUM(TEMPO_ESPERA) AS TEMPO_ESPERA, + SUM(TEMPO_ATENDIMENTO) AS TEMPO_ATENDIMENTO, + SUM(TEMPO_ORIGINADAS) AS TEMPO_ORIGINADAS, + SUM(TEMPO_ABANDONO) AS TEMPO_ABANDONO, + SUM(TRANSBORDANDO) AS TRANSBORDANDO, + SUM(TRANSBORDADA) AS TRANSBORDADA + FROM DADOS_INTERMEDIARIOS + GROUP BY FILA, DATA + ) SELECT - FILA - ,DATA - ,SUM (CASE WHEN EVENTO in('ABANDON', 'COMPLETEAGENT','COMPLETECALLER','TRANSFER','TRANSBORDANDO') THEN 1 ELSE 0 END) AS OFERECIDAS - ,SUM (CASE WHEN (EVENTO = 'ENTERQUEUE') AND (URA > 0) THEN 1 ELSE 0 END) AS ATENDIDAS_URA - ,SUM (CASE WHEN EVENTO = 'ABANDON' THEN 1 ELSE 0 END) AS ABANDONADAS - ,SUM (CASE WHEN EVENTO IN ('COMPLETEAGENT','COMPLETECALLER','TRANSFER') AND SUBSTRING(AGENTE,1,5) <> 'Agent' THEN 1 ELSE 0 END) AS ATENDIDAS_FILA - ,SUM (CASE WHEN EVENTO IN ('COMPLETEAGENT','COMPLETECALLER','TRANSFER') AND SUBSTRING(AGENTE,1,5) = 'Agent' THEN 1 ELSE 0 END) AS ATENDIDAS_PA - ,SUM (CASE WHEN EVENTO IN ('COMPLETAAGENT','COMPLETACALLER','TRANSFERORIG','BUSYS','NOANSWERS') THEN 1 ELSE 0 END) AS ORIGINADAS_PA - ,SUM (CASE WHEN EVENTO IN ('COMPLETEAGENT','COMPLETECALLER','TRANSFER') AND strtoint(param1) <= '30' AND SUBSTRING(AGENTE,1,5) = 'Agent' THEN 1 ELSE 0 END) AS ATENDIDAS_30 - ,SUM (CASE WHEN((EVENTO = 'TRANSFER') or (exists(select '' from pbx_bilhetes where data_bilhete = dados.data_bilhete and accountcode = dados.uniqueid and evento in('COMPLETEAGENT','COMPLETECALLER')))) THEN 1 ELSE 0 END) AS TRANSFERIDAS - ,SUM (CASE WHEN EVENTO IN ('CONNECT') AND strtoint(param1) > '3' THEN 1 ELSE 0 END) AS ESPERA - ,SUM (CASE WHEN EVENTO IN ('CONNECT') AND strtoint(param1) > '3' THEN strtoint(param1) ELSE 0 END) AS TEMPO_ESPERA - ,SUM (CASE WHEN EVENTO IN ('COMPLETEAGENT','COMPLETECALLER') AND strtoint(( case when(coalesce(param2, '') = '')then '0' else param2 end )) > '1' THEN strtoint(param2) ELSE 0 END) AS TEMPO_ATENDIMENTO - ,SUM (CASE WHEN EVENTO IN ('COMPLETAAGENT','COMPLETACALLER') AND strtoint(( case when(coalesce(param2, '') = '')then '0' else param2 end )) > '1' THEN strtoint(param2) ELSE 0 END) AS TEMPO_ORIGINADAS - ,SUM (CASE WHEN EVENTO = 'ABANDON' THEN (CASE WHEN(coalesce(param3, '') = '')THEN 0 ELSE param3::int END) ELSE 0 END) AS TEMPO_ABANDONO - ,SUM (CASE WHEN EVENTO IN('EXITWITHTIMEOUT', 'TRANSBORDANDO') THEN 1 ELSE 0 END) AS TRANSBORDANDO - ,SUM (transbordada) AS TRANSBORDADA - FROM ( - SELECT - a.data_bilhete AS DATA, a.data_bilhete,b.fila, - case when(exists(select '' from pbx_bilhetes where data_bilhete = a.data_bilhete and accountcode = a.uniqueid and evento in('COMPLETEAGENT','COMPLETECALLER','COMPLETAAGENT','COMPLETACALLER')))then ( case when(b.evento in('COMPLETEAGENT','COMPLETECALLER'))then 'TRANSFER' else 'TRANSFERORIG' end) else b.evento end as evento, - case when((evento = 'TRANSBORDADO') OR ((evento = 'ENTERQUEUE') and exists(select '' from ast_eventos_dacs where uid2 = b.uid2 and fila <> b.fila and evento = 'EXITWITHTIMEOUT' and b.id > id)))then 1 else 0 end as transbordada - ,b.param1,b.param2,b.param3,b.param4,b.agente, - (select count(*) from pbx_bilhetes_complemento where uniqueid2 = a.uniqueid and direcao = 'ura') as ura, a.uniqueid - FROM pbx_eventos_dacs b - INNER JOIN pbx_bilhetes a on a.uniqueid = b.uid2 and a.lastapp <> 'Transferred Call' - INNER JOIN pbx_dacs d on d.nome = b.fila - WHERE b.evento in ('ABANDON','COMPLETEAGENT','COMPLETECALLER', 'COMPLETAAGENT','COMPLETACALLER','CONNECT','ENTERQUEUE','TRANSFER','TRANSFERORIG', 'EXITWITHTIMEOUT', 'TRANSBORDANDO', 'TRANSBORDADO','BUSYS','NOANSWERS') - AND a.data_bilhete >= '$iniMes' - AND a.data_bilhete <= '$fimMes' - AND d.id = '$dac' - AND 1 = CASE WHEN(b.evento = 'ABANDON')then (case when(not exists(select '' from ast_eventos_dacs where uid2 = b.uid2 and evento = 'TRANSBORDANDO' and fila = b.fila)) then 1 else 0 end) else 1 end - ) AS DADOS - - GROUP BY FILA, DATA - ) AS DADOS ORDER BY 2"; + FILA, + DATA, + OFERECIDAS, + ATENDIDAS_URA, + ABANDONADAS, + ATENDIDAS_FILA, + ATENDIDAS_PA, + ORIGINADAS_PA, + ATENDIDAS_30, + TRANSFERIDAS, + ESPERA, + ROUND(CASE WHEN ESPERA = 0 THEN 0 ELSE (TEMPO_ESPERA / ESPERA) END) * INTERVAL '1 SECOND' AS TME, + ROUND(CASE WHEN ATENDIDAS_PA = 0 THEN 0 ELSE (TEMPO_ATENDIMENTO / ATENDIDAS_PA) END) * INTERVAL '1 SECOND' AS TMA, + ROUND(CASE WHEN ABANDONADAS = 0 THEN 0 ELSE (TEMPO_ABANDONO / ABANDONADAS) END) * INTERVAL '1 SECOND' AS TMAB, + (CASE WHEN (ATENDIDAS_PA::FLOAT + ABANDONADAS::FLOAT) = 0 THEN 0 ELSE ATENDIDAS_30::FLOAT / (ATENDIDAS_PA::FLOAT + ABANDONADAS::FLOAT) END * 100)::NUMERIC(5,2) AS INB, + (CASE WHEN OFERECIDAS::FLOAT = 0 THEN 0 ELSE (ABANDONADAS::FLOAT / OFERECIDAS::FLOAT) END * 100)::NUMERIC(5,2) AS IAB, + TEMPO_ESPERA, + TEMPO_ATENDIMENTO, + TEMPO_ORIGINADAS, + TEMPO_ABANDONO, + TRANSBORDADA, + TRANSBORDANDO + FROM AGREGADOS + ORDER BY DATA;"; $subQuery = "SELECT date_part('day', COALESCE(entrada_pausa, login)::DATE) AS data, COUNT(entrada_pausa) AS numPausa,