From 3aaaba728fc8298f658a7cff0d0552b771b9e968 Mon Sep 17 00:00:00 2001 From: Matheo Bonucia Date: Mon, 15 Jul 2024 18:11:45 +0000 Subject: [PATCH] refatorado views-mod feito para 1.9 anteriormente --- projeto/base/sql/view-1.9.0.sql | 890 ++++++++++++++++++++++++-------- 1 file changed, 675 insertions(+), 215 deletions(-) diff --git a/projeto/base/sql/view-1.9.0.sql b/projeto/base/sql/view-1.9.0.sql index 2a20786e..bf387cb1 100644 --- a/projeto/base/sql/view-1.9.0.sql +++ b/projeto/base/sql/view-1.9.0.sql @@ -1,229 +1,689 @@ -DROP VIEW IF exists pabx_agentes; -CREATE OR REPLACE VIEW pabx_agentes - AS SELECT pbx_usuarios.id AS agt_id, - pbx_usuarios.nome AS agt_nome, - pbx_usuarios.apelido AS agt_login, - pbx_usuarios.matricula AS agt_matricula, - pbx_usuarios.email AS agt_email, - pbx_usuarios.penalidade AS agt_penalidade, - pbx_usuarios.dac_padrao AS fila_id, - pbx_usuarios.org_padrao AS org_id - FROM pbx_usuarios - WHERE pbx_usuarios.delete_ = 0; - -DROP VIEW IF exists pbx_ramais; -CREATE OR REPLACE VIEW pbx_ramais -AS SELECT a.id, - 'SIP'::character varying(16) AS tipo_ramal, - a.nome, - a.dispositivo, - a.context AS contexto, - a.habilita_prepago, - a.saldo_prepago, - a.ramalsecretaria, - a.sigame_interno, - a.sigame_externo, - a.sigame_naoatende, - a.sigame_ocupado, - a.extranet, - a.org_id - FROM pbx_sip_ramais a +CREATE OR REPLACE VIEW public.pbx_dacs AS +SELECT pbx_queues_grupos.id, + pbx_queues_grupos.nome, + pbx_queues_grupos.numero, + pbx_queues_grupos.status, + pbx_queues_grupos.org_id + FROM pbx_queues_grupos; + + +CREATE OR REPLACE VIEW public.pabx_agentes_eventos AS +SELECT a.id AS agtevt_id, + a.id_dac AS fila_id, + a.matricula AS agt_matricula, + a.ramal AS ramal_numero, + a.entrada_pausa AS agtevt_entrada_pausa, + a.saida_pausa AS agtevt_saida_pausa, + a.id_motivo_pausa AS pausa_id, + a.login AS agtevt_hora_login, + a.logoff AS agtevt_hora_logoff, + a.org_id + FROM pbx_eventos_agentes a; + + + drop view if exists pabx_bilhetes; + CREATE OR REPLACE VIEW public.pabx_bilhetes AS + SELECT a.id_bilhetes AS blt_id, + a.calldate AS blt_data_hora, + a.src AS blt_origem, + a.dst AS blt_destino, + a.billsec AS blt_tempo_conversacao, + a.duration AS blt_tempo_atendimento, + a.accountcode AS blt_id_transfer, + a.uniqueid AS blt_id_chamada, + a.userfield AS blt_nome_audio, + a.data_bilhete AS blt_data, + a.org_id + FROM pbx_bilhetes a + WHERE a.lastapp::text <> 'Transferred Call'::text ; + + + +DROP VIEW IF EXISTS pabx_bilhetes_complemento; +CREATE OR REPLACE VIEW public.pabx_bilhetes_complemento +AS SELECT pbx_bilhetes_complemento.id AS blc_id, + pbx_bilhetes_complemento.uniqueid2 AS blt_id_chamada, + pbx_bilhetes_complemento.direcao AS blc_direcao, + pbx_bilhetes_complemento.destino AS blc_destino, + pbx_bilhetes_complemento.data_registro AS data_hora + ,org_id FROM pbx_bilhetes_complemento; + + +DROP VIEW IF EXISTS pabx_classificacao; +CREATE OR REPLACE VIEW public.pabx_classificacao + AS SELECT pbx_classifica_atendimento.clas_id, + pbx_classifica_atendimento.clas_descricao + ,org_id FROM pbx_classifica_atendimento; + + +DROP VIEW IF EXISTS pabx_filas; +CREATE OR REPLACE VIEW public.pabx_filas + AS SELECT pbx_dacs.id AS fila_id, + pbx_dacs.nome AS fila_nome + ,org_id FROM pbx_dacs + WHERE pbx_dacs.status = 'A'::bpchar ; + + +DROP VIEW IF EXISTS pabx_item_classificacao; +CREATE OR REPLACE VIEW public.pabx_item_classificacao + AS SELECT pbx_classifica_item.clit_id, + pbx_classifica_item.clas_id, + pbx_classifica_item.clit_descricao + ,org_id FROM pbx_classifica_item; + + +DROP VIEW IF EXISTS pabx_pausas; +CREATE OR REPLACE VIEW public.pabx_pausas + AS SELECT pbx_motivos_pausas.id AS pausa_id, + pbx_motivos_pausas.motivo AS pausa_nome, + pbx_motivos_pausas.produtiva AS pausa_produtiva + ,org_id FROM pbx_motivos_pausas; + + +DROP VIEW IF EXISTS pabx_pesquisa; +CREATE OR REPLACE VIEW public.pabx_pesquisa + AS SELECT pbx_pesquisa.pp_id, + pbx_pesquisa.pp_nome, + pbx_pesquisa.pp_data_inicio, + pbx_pesquisa.pp_data_fim, + pbx_pesquisa.pp_audio_saudacao, + pbx_pesquisa.pp_audio_encerramento, + pbx_pesquisa.pp_status, + pbx_pesquisa.pp_data + ,org_id FROM pbx_pesquisa; + + +DROP VIEW IF EXISTS pabx_pesquisa_liberacao; +CREATE OR REPLACE VIEW public.pabx_pesquisa_liberacao + AS SELECT pbx_pesquisa_liberacao.pl_id, + pbx_pesquisa_liberacao.pp_id, + pbx_pesquisa_liberacao.pl_descricao, + pbx_pesquisa_liberacao.pl_data_inicio, + pbx_pesquisa_liberacao.pl_data_fim, + pbx_pesquisa_liberacao.pl_ativa, + pbx_pesquisa_liberacao.pl_data + ,org_id FROM pbx_pesquisa_liberacao; + + +DROP VIEW IF EXISTS pabx_pesquisa_movimento; +CREATE OR REPLACE VIEW public.pabx_pesquisa_movimento + AS SELECT pbx_pesquisa_movimento.pm_id, + pbx_pesquisa_movimento.pl_id, + pbx_pesquisa_movimento.pp_id, + pbx_pesquisa_movimento.pq_id, + pbx_pesquisa_movimento.po_id, + pbx_pesquisa_movimento.uniqueid AS blt_id_chamada, + pbx_pesquisa_movimento.pm_data, + pbx_pesquisa_movimento.id_dac AS fila_id + ,org_id FROM pbx_pesquisa_movimento; + + +DROP VIEW IF EXISTS pabx_pesquisa_opcoes; +CREATE OR REPLACE VIEW public.pabx_pesquisa_opcoes + AS SELECT pbx_pesquisa_opcoes.pp_id, + pbx_pesquisa_opcoes.pq_id, + pbx_pesquisa_opcoes.po_id, + pbx_pesquisa_opcoes.po_display, + pbx_pesquisa_opcoes.po_opcao, + pbx_pesquisa_opcoes.po_status + ,org_id FROM pbx_pesquisa_opcoes; + + +DROP VIEW IF EXISTS pabx_pesquisa_questoes; +CREATE OR REPLACE VIEW public.pabx_pesquisa_questoes + AS SELECT pbx_pesquisa_questoes.pp_id, + pbx_pesquisa_questoes.pq_id, + pbx_pesquisa_questoes.pq_display, + pbx_pesquisa_questoes.pq_questao, + pbx_pesquisa_questoes.pq_audio, + pbx_pesquisa_questoes.pq_status + ,org_id FROM pbx_pesquisa_questoes; + + +DROP VIEW IF EXISTS pabx_ramais; +CREATE OR REPLACE VIEW public.pabx_ramais + AS SELECT pbx_sip_ramais.nome AS ramal_numero, + pbx_sip_ramais.port AS ramal_porta, + pbx_sip_ramais.callerid AS ramal_bina + ,org_id FROM pbx_sip_ramais; + + +DROP VIEW IF EXISTS pabx_registra_classificacao; +CREATE OR REPLACE VIEW public.pabx_registra_classificacao + AS SELECT a.matricula AS agt_matricula, + a.clas_id, + a.clit_id, + a.id_bilhetes AS blt_id_chamada, + a.data_reg AS rcl_data_hora, + a.id_dac AS fila_id + ,org_id FROM pbx_classifica_reg a; + + +DROP VIEW IF EXISTS pbx_dacs_api; +CREATE OR REPLACE VIEW public.pbx_dacs_api + AS SELECT pbx_queues_grupos.id, + pbx_queues_grupos.nome, + pbx_queues_grupos.numero, + pbx_queues_grupos.status + ,org_id FROM pbx_queues_grupos; + + +DROP VIEW IF exists pbx_lista_arquivo_som; +CREATE OR REPLACE VIEW pbx_lista_arquivo_som AS + SELECT a.tipo, + a.arq_som, + org_id + FROM ( SELECT 'ura'::text AS tipo, + pbx_ura.som_ura AS arq_som, + org_id + FROM pbx_ura + + UNION + + SELECT 'anuncio'::text AS tipo, + pbx_anuncios.musica AS arq_som, + org_id + FROM pbx_anuncios + + UNION + + SELECT 'conferencia'::text AS tipo, + pbx_conferencia.anuncio AS arq_som, + org_id + FROM pbx_conferencia) a + WHERE btrim(a.arq_som::text) <> ' '::text ; + + +DROP VIEW IF EXISTS pbx_nao_classificado; +CREATE OR REPLACE VIEW public.pbx_nao_classificado + AS + SELECT + a.id_bilhetes, + a.data_bilhete, + a.calldate, + rtrim(a.src::text) AS origem, + rtrim(a.dst::text) AS destino, + rtrim(a.uniqueid::text) AS uniqueid, + a.duration, + a.billsec, + rtrim(a.userfield::text) AS audio, + c.id AS fila_id, + rtrim(b.fila::text) AS fila, + "substring"(b.agente::text, 7, 4) AS agente, + d.apelido AS nome_agente, + rtrim(b.evento::text) AS evento, + rtrim(b.param1::text) AS espera, + rtrim(b.param2::text) AS tempo_atendimento + ,a.org_id FROM + pbx_bilhetes a + JOIN + pbx_eventos_dacs b ON b.uid2::text = a.uniqueid::text and a.org_id = b.org_id + JOIN + pbx_dacs c ON c.nome::text = b.fila::text AND c.org_id = a.org_id + JOIN + pbx_usuarios d ON d.matricula::text = "substring"(b.agente::text, 7, 4) + JOIN + pbx_organizacao_usuarios e on e.id_usuario = d.id and e.id_organizacao = a.org_id + WHERE + a.lastapp::text <> 'Transferred Call'::text + AND (b.evento::text = ANY (ARRAY['COMPLETEAGENT'::character varying::text, 'COMPLETECALLER'::character varying::text, 'COMPLETAAGENT'::character varying::text, 'COMPLETACALLER'::character varying::text, 'TRANSFER'::character varying::text, 'TRANSFERORIG'::character varying::text])) + AND NOT (EXISTS (SELECT ' '::text ,org_id FROM pbx_classifica_reg WHERE pbx_classifica_reg.id_bilhetes::text = a.uniqueid::text)) ; + + + DROP VIEW IF EXISTS pbx_opcao_acao; + CREATE OR REPLACE VIEW public.pbx_opcao_acao + AS SELECT 'ramal'::text AS opcao, + r.nome::text AS id, + r.nome AS descricao + ,r.org_id FROM pbx_sip_ramais r + WHERE r.nome::text <> '0'::text + + UNION all + + SELECT 'ura'::text AS opcao, + u.id::text AS id, + u.nome AS descricao + ,u.org_id FROM pbx_ura u + + UNION all + + SELECT 'voice'::text AS opcao, + v.caixa_postal::text AS id, + v.caixa_postal AS descricao + ,v.org_id FROM pbx_voicemail_usuarios v + + UNION all + + SELECT 'grupo'::text AS opcao, + g.numero::text AS id, + g.descricao + ,g.org_id FROM pbx_grupos g + + UNION all + + SELECT 'filas'::text AS opcao, + qg.numero::text AS id, + qg.nome AS descricao + ,qg.org_id FROM pbx_queues_grupos qg + WHERE qg.status = 'A'::bpchar + + UNION all + + SELECT 'horarios'::text AS opcao, + a.id::text AS id, + a.nome AS descricao + ,a.org_id FROM pbx_horarios a, + pbx_horarios_itens b + WHERE b.id_horario = a.id + + UNION all + + SELECT 'disa'::text AS opcao, + d.numero::text AS id, + d.numero AS descricao + ,d.org_id FROM pbx_disa d + + + UNION all + + SELECT 'anuncios'::text AS opcao, + an.id::text AS id, + an.nome AS descricao + ,an.org_id FROM pbx_anuncios an + + UNION all + + SELECT 'conferencia'::text AS opcao, + conf.numero::text AS id, + conf.numero AS descricao + ,org_id FROM pbx_conferencia conf + + UNION all + + SELECT 'callback'::text AS opcao, + callb.id::text AS id, + callb.descricao + ,org_id FROM pbx_callback callb + + UNION all + + SELECT 'rotaInterna'::text AS opcao, + rs.id::text AS id, + rs.nome AS descricao + ,org_id FROM pbx_rotas_saida rs + WHERE upper(rs.tipo::text) = 'I'::text + + UNION all + + SELECT 'departamento'::text AS opcao, + a.id::text AS id, + (b.nome::text || '/'::text) || a.nome_depto::text AS descricao + ,a.org_id FROM pbx_departamentos a, + pbx_empresa b + WHERE b.id = a.empresa + + UNION all + + SELECT 'integativa'::text AS opcao, + b.itgm_id::text AS id, + (a.itgc_nome::text || '-'::text) || b.itgm_nome::text AS descricao + ,a.org_id FROM pbx_integracao_configuracao a, + pbx_integracao_metodo b + WHERE b.itgc_id = a.itgc_id AND b.itgm_retorno = 1 + ORDER BY 3; + + DROP VIEW IF EXISTS pbx_opcoes; + CREATE OR REPLACE VIEW public.pbx_opcoes +AS ( SELECT 'ramal'::character varying(100) AS value, + 'Ramal'::character varying(100) AS name + ,org_id FROM pbx_sip_ramais + LIMIT 1) + UNION ALL - SELECT b.id, - 'IAX2'::character varying(16) AS tipo_ramal, - b.nome, - b.dispositivo, - b.context AS contexto, - b.habilita_prepago, - b.saldo_prepago, - b.ramalsecretaria, - b.sigame_interno, - b.sigame_externo, - b.sigame_naoatende, - b.sigame_ocupado, - ''::character varying(256) AS extranet, - b.org_id - FROM pbx_iax_pbx b + +( SELECT 'filas'::character varying(100) AS value, + 'Fila'::character varying(100) AS name + ,org_id FROM pbx_queues_grupos + WHERE pbx_queues_grupos.status = 'A'::bpchar + LIMIT 1) + UNION ALL - SELECT c.id, - 'PBX'::text AS tipo_ramal, - c.numero AS nome, - (c.dispositivo::text || '/'::text) || c.numero::text AS dispositivo, - c.contexto, - c.habilita_prepago, - c.saldo_prepago, - c.ramalsecretaria, - c.sigame_interno, - c.sigame_externo, - c.sigame_naoatende, - c.sigame_ocupado, - ''::character varying(256) AS extranet, - c.org_id - FROM pbx_ramais_pbx c - ORDER BY 1; --------------------------------------------------------- -DROP VIEW IF exists pbx_ramais_mesa; -CREATE OR REPLACE VIEW pbx_ramais_mesa -AS SELECT 0 AS tipo, - pbx_sip_ramais.id, - pbx_sip_ramais.nome, - pbx_sip_ramais.dispositivo, - pbx_sip_ramais.callerid, - 'SIP'::text AS tipo_table, - pbx_sip_ramais.conta_senha, - ''::character varying AS ddd, - pbx_sip_ramais.context AS contexto, - pbx_sip_ramais.org_id as org_id - FROM pbx_sip_ramais + +( SELECT 'ura'::character varying(100) AS value, + 'URA'::character varying(100) AS name + ,org_id FROM pbx_ura + LIMIT 1) + UNION ALL - SELECT 1 AS tipo, - 0 AS id, - pbx_ramais_agenda.rma_telefone AS nome, - pbx_ramais_agenda.rma_telefone AS dispositivo, - pbx_ramais_agenda.rma_nome AS callerid, - 'AGD'::text AS tipo_table, - 'F'::character varying AS conta_senha, - pbx_ramais_agenda.ddd, - ' '::character varying AS contexto, - pbx_ramais_agenda.org_id AS org_id - FROM pbx_ramais_agenda + +( SELECT 'voice'::character varying(100) AS value, + 'VoiceMail'::character varying(100) AS name + ,org_id FROM pbx_voicemail_usuarios + LIMIT 1) + UNION ALL - SELECT 0 AS tipo, - pbx_iax_pbx.id, - pbx_iax_pbx.nome, - pbx_iax_pbx.dispositivo, - pbx_iax_pbx.nome AS callerid, - 'IAX'::text AS tipo_table, - pbx_iax_pbx.conta_senha, - ''::character varying AS ddd, - pbx_iax_pbx.context AS contexto, - pbx_iax_pbx.org_id AS org_id - FROM pbx_iax_pbx - ORDER BY 5; --------------------------------------------------------- -DROP VIEW IF exists pbx_troncos; -CREATE OR REPLACE VIEW pbx_troncos -AS SELECT 'SIP'::text AS tipo, - pbx_troncos_sip.id, - pbx_troncos_sip.nome, - pbx_troncos_sip.max_ligacoes, - pbx_troncos_sip.nome AS username, - pbx_troncos_sip.contrato, - pbx_troncos_sip.callerid, - pbx_troncos_sip.context, - pbx_troncos_sip.callerid AS callerid_tronco, - pbx_troncos_sip.portabilidade, - pbx_troncos_sip.org_id - FROM pbx_troncos_sip + +( SELECT 'grupo'::character varying(100) AS value, + 'Grupo'::character varying(100) AS name + ,org_id FROM pbx_grupo + LIMIT 1) + UNION ALL - SELECT 'IAX2'::text AS tipo, - pbx_troncos_iax.id, - pbx_troncos_iax.nome, - pbx_troncos_iax.max_ligacoes, - pbx_troncos_iax.nome AS username, - pbx_troncos_iax.contrato, - pbx_troncos_iax.callerid, - pbx_troncos_iax.context, - pbx_troncos_iax.callerid AS callerid_tronco, - pbx_troncos_iax.portabilidade, - pbx_troncos_iax.org_id - FROM pbx_troncos_iax + +( SELECT 'disa'::character varying(100) AS value, + 'Disa'::character varying(100) AS name + ,org_id FROM pbx_disa + LIMIT 1) + UNION ALL - SELECT 'KHOMP'::text AS tipo, - pbx_troncos_khomp.id, - pbx_troncos_khomp.descricao AS nome, - pbx_troncos_khomp.max_ligacoes, - pbx_troncos_khomp.grupo AS username, - pbx_troncos_khomp.contrato, - pbx_troncos_khomp.callerid, - pbx_troncos_khomp.contexto AS context, - pbx_troncos_khomp.callerid AS callerid_tronco, - pbx_troncos_khomp.portabilidade, - pbx_troncos_khomp.org_id - FROM pbx_troncos_khomp; - - --------------------------- -DROP VIEW IF exists pbx_lista_arquivo_som; -CREATE OR REPLACE VIEW pbx_lista_arquivo_som AS -SELECT a.tipo, - a.arq_som, - org_id - FROM ( SELECT 'ura'::text AS tipo, - pbx_ura.som_ura AS arq_som, - org_id - FROM pbx_ura - UNION - SELECT 'anuncio'::text AS tipo, - pbx_anuncios.musica AS arq_som, - org_id - FROM pbx_anuncios - UNION - SELECT 'conferencia'::text AS tipo, - pbx_conferencia.anuncio AS arq_som, - org_id - FROM pbx_conferencia) a - WHERE btrim(a.arq_som::text) <> ''::text; - - --------------------------- +( SELECT 'horarios'::character varying(100) AS value, + 'Horários'::character varying(100) AS name + ,org_id FROM pbx_horarios + LIMIT 1) -DROP VIEW IF EXISTS pbx_rotas; +UNION ALL + +( SELECT 'anuncios'::character varying(100) AS value, + 'Anúncios'::character varying(100) AS name + ,org_id FROM pbx_anuncios + LIMIT 1) + +UNION ALL + +( SELECT 'conferencia'::character varying(100) AS value, + 'Conferências'::character varying(100) AS name + ,org_id FROM pbx_conferencia + LIMIT 1) + +UNION ALL + +( SELECT 'callback'::character varying(100) AS value, + 'CallBack'::character varying(100) AS name + ,org_id FROM pbx_callback + LIMIT 1) + +UNION ALL + +( SELECT 'rotaInterna'::character varying(100) AS value, + 'Rotas Internas'::character varying(100) AS name + ,org_id FROM pbx_rotas_saida + WHERE pbx_rotas_saida.tipo::text = 'I'::text + LIMIT 1) + +UNION ALL + +( SELECT 'repetir'::character varying(100) AS value, + 'Repetir'::character varying(100) AS name + ,org_id FROM pbx_rotas_saida + LIMIT 1) -CREATE OR REPLACE VIEW public.pbx_rotas AS -SELECT - 'S'::text AS tipo, - pbx_rotas_saida.id, - pbx_rotas_saida.nome, - pbx_rotas_saida.org_id -FROM - pbx_rotas_saida UNION ALL -SELECT - 'E'::text AS tipo, + +( SELECT 'desligar'::character varying(100) AS value, + 'Desligar'::character varying(100) AS name + ,org_id FROM pbx_rotas_saida + LIMIT 1) + +UNION ALL + +( SELECT 'integativa'::character varying(100) AS value, + 'Integração Ativa'::character varying(100) AS name + ,a.org_id FROM pbx_integracao_configuracao a, + pbx_integracao_metodo b + WHERE b.itgc_id = a.itgc_id + LIMIT 1); + + DROP VIEW IF EXISTS pbx_prepago; + CREATE OR REPLACE VIEW public.pbx_prepago + AS SELECT 0 AS tipo, + 'sip'::text AS desc_tipo, + pbx_sip_ramais.nome::text AS id, + 'pbx_sip_ramais'::text AS tabela, + 'nome'::text AS coluna, + pbx_sip_ramais.habilita_prepago, + pbx_sip_ramais.saldo_prepago + ,org_id FROM pbx_sip_ramais + + UNION ALL + + SELECT 0 AS tipo, + 'iax'::text AS desc_tipo, + pbx_iax_pbx.nome::text AS id, + 'pbx_iax_pbx'::text AS tabela, + 'nome'::text AS coluna, + pbx_iax_pbx.habilita_prepago, + pbx_iax_pbx.saldo_prepago + ,org_id FROM pbx_iax_pbx + + UNION ALL + + SELECT 0 AS tipo, + 'dgv'::text AS desc_tipo, + pbx_dgv.numero::text AS id, + 'pbx_dgv'::text AS tabela, + 'numero'::text AS coluna, + pbx_dgv.habilita_prepago, + pbx_dgv.saldo_prepago + ,org_id FROM pbx_dgv + + UNION ALL + + SELECT 1 AS tipo, + 'conta'::text AS desc_tipo, + pbx_cs_usuarios.matricula::text AS id, + 'pbx_cs_usuarios'::text AS tabela, + 'matricula'::text AS coluna, + pbx_cs_usuarios.habilita_prepago, + pbx_cs_usuarios.saldo_prepago + ,org_id FROM pbx_cs_usuarios + WHERE pbx_cs_usuarios.status = 'A'::bpchar ; + + +DROP VIEW IF EXISTS pbx_queues_grupos_mesa; +CREATE OR REPLACE VIEW public.pbx_queues_grupos_mesa + AS SELECT pbx_queues_grupos.id, + pbx_queues_grupos.nome + ,org_id FROM pbx_queues_grupos + WHERE pbx_queues_grupos.status = 'A'::bpchar + ORDER BY pbx_queues_grupos.nome; + +DROP VIEW IF EXISTS pbx_ramais; +CREATE OR REPLACE VIEW pbx_ramais AS + SELECT a.id, + 'SIP'::character varying(16) AS tipo_ramal, + a.nome, + a.dispositivo, + a.context AS contexto, + a.habilita_prepago, + a.saldo_prepago, + a.ramalsecretaria, + a.sigame_interno, + a.sigame_externo, + a.sigame_naoatende, + a.sigame_ocupado, + a.extranet, + a.org_id + FROM pbx_sip_ramais a + + UNION ALL + + SELECT b.id, + 'IAX2'::character varying(16) AS tipo_ramal, + b.nome, + b.dispositivo, + b.context AS contexto, + b.habilita_prepago, + b.saldo_prepago, + b.ramalsecretaria, + b.sigame_interno, + b.sigame_externo, + b.sigame_naoatende, + b.sigame_ocupado, + ''::character varying(256) AS extranet, + b.org_id + FROM pbx_iax_pbx b + + UNION ALL + + SELECT c.id, + 'PBX'::text AS tipo_ramal, + c.numero AS nome, + (c.dispositivo::text || '/'::text) || c.numero::text AS dispositivo, + c.contexto, + c.habilita_prepago, + c.saldo_prepago, + c.ramalsecretaria, + c.sigame_interno, + c.sigame_externo, + c.sigame_naoatende, + c.sigame_ocupado, + ''::character varying(256) AS extranet, + c.org_id + FROM pbx_ramais_pbx c + + ORDER BY 1; + + DROP VIEW IF EXISTS pbx_ramais_mesa; + CREATE OR REPLACE VIEW pbx_ramais_mesa AS + SELECT 0 AS tipo, + pbx_sip_ramais.id, + pbx_sip_ramais.nome, + pbx_sip_ramais.dispositivo, + pbx_sip_ramais.callerid, + 'SIP'::text AS tipo_table, + pbx_sip_ramais.conta_senha, + ' '::character varying AS ddd, + pbx_sip_ramais.context AS contexto, + pbx_sip_ramais.org_id as org_id + FROM pbx_sip_ramais + + UNION ALL + + SELECT 1 AS tipo, + 0 AS id, + pbx_ramais_agenda.rma_telefone AS nome, + pbx_ramais_agenda.rma_telefone AS dispositivo, + pbx_ramais_agenda.rma_nome AS callerid, + 'AGD'::text AS tipo_table, + 'F'::character varying AS conta_senha, + pbx_ramais_agenda.ddd, + ' '::character varying AS contexto, + pbx_ramais_agenda.org_id AS org_id + FROM pbx_ramais_agenda + + UNION ALL + + SELECT 0 AS tipo, + pbx_iax_pbx.id, + pbx_iax_pbx.nome, + pbx_iax_pbx.dispositivo, + pbx_iax_pbx.nome AS callerid, + 'IAX'::text AS tipo_table, + pbx_iax_pbx.conta_senha, + ' '::character varying AS ddd, + pbx_iax_pbx.context AS contexto, + pbx_iax_pbx.org_id AS org_id + FROM pbx_iax_pbx + + ORDER BY 5; + +DROP VIEW IF EXISTS pbx_rotas; +CREATE OR REPLACE VIEW public.pbx_rotas + AS SELECT 'S'::text AS tipo, + pbx_rotas_saida.id, + pbx_rotas_saida.nome + ,org_id FROM pbx_rotas_saida + + UNION all + + SELECT 'E'::text AS tipo, pbx_rotas_entrada.id, - pbx_rotas_entrada.nome, - pbx_rotas_entrada.org_id -FROM - pbx_rotas_entrada -ORDER BY - 3; + pbx_rotas_entrada.nome + ,org_id FROM pbx_rotas_entrada + ORDER BY 3; + +DROP VIEW IF exists pbx_troncos; +CREATE OR REPLACE VIEW pbx_troncos AS + SELECT 'SIP'::text AS tipo, + pbx_troncos_sip.id, + pbx_troncos_sip.nome, + pbx_troncos_sip.max_ligacoes, + pbx_troncos_sip.nome AS username, + pbx_troncos_sip.contrato, + pbx_troncos_sip.callerid, + pbx_troncos_sip.context, + pbx_troncos_sip.callerid AS callerid_tronco, + pbx_troncos_sip.portabilidade, + pbx_troncos_sip.org_id + FROM pbx_troncos_sip - --------------------------- + UNION ALL -DROP VIEW IF EXISTS pbx_nao_classificado; + SELECT 'IAX2'::text AS tipo, + pbx_troncos_iax.id, + pbx_troncos_iax.nome, + pbx_troncos_iax.max_ligacoes, + pbx_troncos_iax.nome AS username, + pbx_troncos_iax.contrato, + pbx_troncos_iax.callerid, + pbx_troncos_iax.context, + pbx_troncos_iax.callerid AS callerid_tronco, + pbx_troncos_iax.portabilidade, + pbx_troncos_iax.org_id + FROM pbx_troncos_iax + + UNION ALL + + SELECT 'KHOMP'::text AS tipo, + pbx_troncos_khomp.id, + pbx_troncos_khomp.descricao AS nome, + pbx_troncos_khomp.max_ligacoes, + pbx_troncos_khomp.grupo AS username, + pbx_troncos_khomp.contrato, + pbx_troncos_khomp.callerid, + pbx_troncos_khomp.contexto AS context, + pbx_troncos_khomp.callerid AS callerid_tronco, + pbx_troncos_khomp.portabilidade, + pbx_troncos_khomp.org_id + FROM pbx_troncos_khomp + + ORDER BY 1; + +DROP VIEW IF EXISTS pbx_usuarios_cs; +CREATE OR REPLACE VIEW public.pbx_usuarios_cs + AS SELECT pbx_cs_usuarios.id, + pbx_cs_usuarios.nome, + pbx_cs_usuarios.apelido, + pbx_cs_usuarios.empresa, + pbx_cs_usuarios.departamento, + pbx_cs_usuarios.matricula + ,org_id FROM pbx_cs_usuarios + WHERE pbx_cs_usuarios.status = 'A'::bpchar ; + -CREATE OR REPLACE VIEW public.pbx_nao_classificado AS -SELECT - a.id_bilhetes, - a.data_bilhete, - a.calldate, - rtrim(a.src::text) AS origem, - rtrim(a.dst::text) AS destino, - rtrim(a.uniqueid::text) AS uniqueid, - a.duration, - a.billsec, - rtrim(a.userfield::text) AS audio, - c.id AS fila_id, - rtrim(b.fila::text) AS fila, - "substring"(b.agente::text, 7, 4) AS agente, - d.apelido AS nome_agente, - rtrim(b.evento::text) AS evento, - rtrim(b.param1::text) AS espera, - rtrim(b.param2::text) AS tempo_atendimento, - a.org_id -FROM - pbx_bilhetes a, - pbx_eventos_dacs b, - pbx_dacs c, - pbx_usuarios d -WHERE - b.uid2::text = a.uniqueid::text - AND c.nome::text = b.fila::text - AND d.matricula::text = "substring"(b.agente::text, 7, 4) - AND a.lastapp::text <> 'Transferred Call'::text - AND (b.evento::text = ANY (ARRAY['COMPLETEAGENT'::character varying::text, 'COMPLETECALLER'::character varying::text, 'COMPLETAAGENT'::character varying::text, 'COMPLETACALLER'::character varying::text, 'TRANSFER'::character varying::text, 'TRANSFERORIG'::character varying::text])) - AND NOT (EXISTS ( - SELECT ''::text - FROM pbx_classifica_reg - WHERE pbx_classifica_reg.id_bilhetes::text = a.uniqueid::text - )); +DROP VIEW IF EXISTS pbx_usuarios_dacs; +CREATE OR REPLACE VIEW public.pbx_usuarios_dacs AS + SELECT + a.user_id AS id_usuario, + c.apelido, + c.nome, + a.gp_id, + d.gp_nome, + b.id AS id_dac, + e.nome AS nome_dac + ,a.org_id FROM + pbx_grupo_usuario a + JOIN + pbx_fila_grupos b ON b.gp_id = a.gp_id + JOIN + pbx_usuarios c ON c.id = a.user_id + JOIN + pbx_grupo d ON d.gp_id = a.gp_id + JOIN + pbx_dacs e ON e.id = b.id + JOIN + pbx_organizacao_usuarios f on f.id_usuario = c.id and f.id_organizacao = a.org_id + AND b.org_id = a.org_id + AND d.org_id = a.org_id + AND e.org_id = a.org_id; \ No newline at end of file