Files
Customer/CEVA/ceva.sql
Sander Schepers c1eb9453ef CEVA#72553 Rapportages
svn path=/Customer/trunk/; revision=56515
2022-07-07 13:49:07 +00:00

497 lines
18 KiB
SQL

-- Script containing customer specific configuration sql statements for CEVA Logistics
-- $Revision$
-- $Id$
DEFINE thisfile = 'CEVA.SQL'
DEFINE dbuser = '^CEVA'
DEFINE custid = 'CEVA'
SET ECHO ON
SET DEFINE ON
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
WHENEVER SQLERROR EXIT;
SELECT adm.scriptspoolfile('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL;
WHENEVER SQLERROR CONTINUE;
SPOOL &fcltlogfile
SET DEFINE OFF
------ payload begin ------
CREATE OR REPLACE FORCE VIEW CEVA_V_RAP_VIS_NOCHECKOUT
(
BEZ_AFSPRAAK_KEY,
AFSPRAAKDATUM,
AFSPRAAKTIJDVANAF,
AFSPRAAKTIJDTOT,
GASTHEER,
BEZ_BEZOEK_KEY,
BEZOEKER,
BEDRIJF,
BADGENR,
TIJDBINNEN,
KENTEKEN,
TELEFOON
)
AS
SELECT
a.bez_afspraak_key,
TRUNC (a.bez_afspraak_datum) as datum_afspraak,
TO_CHAR (a.bez_afspraak_datum, 'HH24:MI') as vanaf,
TO_CHAR (a.bez_afspraak_eind, 'HH24:MI') as tot,
a.bez_afspraak_gastheer,
b.bez_bezoekers_key,
b.bez_afspraak_naam,
b.bez_afspraak_bedrijf,
b.bez_bezoekers_pasnr,
TO_CHAR (b.bez_bezoekers_done, 'HH24:MI') as TIJDBINNEN,
(SELECT kmw.bez_kenmerkwaarde_waarde
FROM bez_kenmerk km, bez_kenmerkwaarde kmw
WHERE km.bez_kenmerk_key = 1001 -- Key voor 'Licence plate'
AND b.bez_bezoekers_key = kmw.bez_bezoekers_key
AND km.bez_kenmerk_key = kmw.bez_kenmerk_key
AND km.bez_kenmerk_key = kmw.bez_kenmerk_key) as license_plate,
(SELECT kmw.bez_kenmerkwaarde_waarde
FROM bez_kenmerk km, bez_kenmerkwaarde kmw
WHERE km.bez_kenmerk_key = 1002 -- Key voor 'Mobile Phone'
AND b.bez_bezoekers_key = kmw.bez_bezoekers_key
AND km.bez_kenmerk_key = kmw.bez_kenmerk_key
AND km.bez_kenmerk_key = kmw.bez_kenmerk_key) as mobile_phone
FROM
bez_bezoekers b,
bez_afspraak a
WHERE
b.bez_afspraak_key = a.bez_afspraak_key
AND TRUNC (a.bez_afspraak_datum) = TRUNC (SYSDATE)
AND b.bez_bezoekers_done IS NOT NULL
AND b.bez_bezoekers_out IS NULL
-- ER KAN NOG EEN WHERE KOMEN OM TE SCOPEN NAAR LOCATIE
;
-- View om bij te houden welke menu items worden gebruikt.
/* Formatted on 7/10/2019 11:12:54 (QP5 v5.318) */
CREATE OR REPLACE VIEW CEVA_V_RAP_GUI_COUNTER
(
FAC_GUI_COUNTER_KEY,
FAC_GUI_COUNTER_GROUP,
FAC_GUI_COUNTER_INFO,
FAC_GUI_COUNTER_REFKEY,
FAC_GUI_COUNTER_CHOICE,
FAC_GUI_COUNTER_RESULT,
FAC_GUI_COUNTER_DATE,
PRS_PERSLID_KEY,
PRS_PERSLID_NAAM_FULL,
PRS_AFDELING_OMSCHRIJVING,
PRS_BEDRIJF_NAAM
)
AS
SELECT fgc.fac_gui_counter_key,
fgc.fac_gui_counter_group,
fgc.fac_gui_counter_info,
fgc.fac_gui_counter_refkey,
choice.fac_gui_counter_info fac_gui_counter_choice,
result.fac_gui_counter_info fac_gui_counter_result,
fac_gui_counter_date,
fgc.prs_perslid_key,
prs_perslid_naam_full,
afd.prs_afdeling_omschrijving,
bedr.prs_bedrijf_naam
FROM fac_gui_counter fgc,
prs_v_perslid_fullnames pf,
prs_perslid pr,
prs_afdeling afd,
prs_bedrijf bedr,
(SELECT fac_gui_counter_refkey, fac_gui_counter_info
FROM fac_gui_counter fgc
WHERE fac_gui_counter_info IS NOT NULL
AND fac_gui_counter_group = 'searchchoice') choice,
(SELECT fac_gui_counter_refkey, fac_gui_counter_info
FROM fac_gui_counter fgc
WHERE fac_gui_counter_info IS NOT NULL
AND fac_gui_counter_group = 'searchresult') result
WHERE fac_gui_counter_group = 'search'
AND fgc.fac_gui_counter_info IS NOT NULL
AND fgc.prs_perslid_key = pf.prs_perslid_key
AND choice.fac_gui_counter_refkey(+) = fgc.fac_gui_counter_key
AND result.fac_gui_counter_refkey(+) = fgc.fac_gui_counter_key
AND pr.prs_perslid_key = fgc.prs_perslid_key
AND afd.PRS_AFDELING_KEY = pr.prs_afdeling_key
AND bedr.prs_bedrijf_key = afd.prs_bedrijf_key
UNION ALL
SELECT fgc.fac_gui_counter_key,
fgc.fac_gui_counter_group,
fac_usrrap_omschrijving,
fgc.fac_gui_counter_refkey,
NULL,
NULL,
fac_gui_counter_date,
fgc.prs_perslid_key,
prs_perslid_naam_full,
afd.prs_afdeling_omschrijving,
bedr.prs_bedrijf_naam
FROM fac_gui_counter fgc,
prs_v_perslid_fullnames pf,
fac_usrrap fr,
prs_afdeling afd,
prs_perslid pr,
prs_bedrijf bedr
WHERE fgc.fac_gui_counter_group = 'report'
AND fgc.prs_perslid_key = pf.prs_perslid_key(+)
AND fr.fac_usrrap_key(+) = fgc.fac_gui_counter_refkey
AND pr.prs_perslid_key = fgc.prs_perslid_key
AND afd.PRS_AFDELING_KEY = pr.prs_afdeling_key
AND bedr.prs_bedrijf_key = afd.prs_bedrijf_key
UNION ALL
SELECT fgc.fac_gui_counter_key,
fgc.fac_gui_counter_group,
COALESCE (fac_menu_altlabel, lcl.l (fac_menuitems_label)),
fgc.fac_gui_counter_refkey,
NULL,
NULL,
fac_gui_counter_date,
fgc.prs_perslid_key,
prs_perslid_naam_full,
afd.prs_afdeling_omschrijving,
bedr.prs_bedrijf_naam
FROM fac_gui_counter fgc,
prs_v_perslid_fullnames pf,
prs_afdeling afd,
prs_bedrijf bedr,
prs_perslid pr,
fac_menu m,
fac_menuitems mi
WHERE fgc.fac_gui_counter_group = 'menu'
AND fgc.prs_perslid_key = pf.prs_perslid_key(+)
AND m.fac_menu_key = fac_gui_counter_refkey
AND mi.fac_menuitems_key(+) = m.fac_menuitems_key
AND pr.prs_perslid_key = fgc.prs_perslid_key
AND afd.PRS_AFDELING_KEY = pr.prs_afdeling_key
AND bedr.prs_bedrijf_key = afd.prs_bedrijf_key;
CREATE OR REPLACE FORCE VIEW CEVA_V_NOTI_VIS_NOCHECKOUT
(
CODE,
SENDER,
RECEIVER,
TEXT,
KEY,
XKEY
)
AS
SELECT 'CUST01',
NULL,
bez_afspraak_key,
'Bezoekers niet afgemeld',
(SELECT fac_usrrap_key
FROM fac_usrrap
WHERE fac_usrrap_view_name = 'CEVA_V_RAP_VIS_NOCHECKOUT'),
bez_bezoek_key
FROM CEVA_V_RAP_VIS_NOCHECKOUT
;
CREATE OR REPLACE VIEW ceva_v_noti_visitors
AS
SELECT NULL
sender,
NULL
receiver,
'Welcome to CEVA'
text,
'CUST02'
code,
b.bez_bezoekers_key
key,
NULL
xkey,
COALESCE (m.bez_kenmerkwaarde_waarde, b.bez_bezoekers_email)
xemail,
NULL
xmobile,
LISTAGG (bijl.bijlage, '|') WITHIN GROUP (ORDER BY bijl.bijlage)
AS attachments
FROM bez_bezoekers b,
bez_afspraak a,
alg_locatie l,
(SELECT af.bez_afspraak_key, fac_bijlagen_key bijlage
FROM fac_v_bijlagen bij, bez_afspraak af
WHERE fac_bijlagen_module = 'ALG'
AND af.alg_locatie_key = bij.fac_bijlagen_refkey
AND bij.fac_bijlagen_kenmerk_key = 1360) bijl, --Kenmerk attachment notificatie bij locatie (1340 in accept)
(SELECT fac_notificatie_job_nextrun, fac_notificatie_job_lastrun
FROM fac_notificatie_job
WHERE fac_notificatie_job_view = 'CEVA_V_NOTI_VISITORS') n,
(SELECT bk.bez_bezoekers_key, bk.bez_kenmerkwaarde_waarde
FROM bez_kenmerkwaarde bk
WHERE bk.bez_kenmerk_key = 1020 -- kenmerk email (1021 in accept)
AND bk.bez_kenmerkwaarde_verwijder IS NULL) m
WHERE b.bez_afspraak_key = a.bez_afspraak_key
AND a.alg_locatie_key = l.alg_locatie_key
AND a.bez_afspraak_key = bijl.bez_afspraak_key(+)
AND b.bez_bezoekers_key = m.bez_bezoekers_key(+)
AND b.bez_bezoekers_aanmaak BETWEEN n.fac_notificatie_job_lastrun
AND n.fac_notificatie_job_nextrun
GROUP BY alg_onrgoed_keys,
a.bez_afspraak_key,
b.bez_bezoekers_key,
bez_bezoekers_email,
m.bez_kenmerkwaarde_waarde;
CREATE OR REPLACE PACKAGE CEVA
AS
PROCEDURE schonen_personen;
END;
/
-- Dagelijks schonen personen die langer dan een jaar niet hebben ingelogd.
CREATE OR REPLACE PACKAGE BODY CEVA
AS
PROCEDURE schonen_personen
AS
c_applname VARCHAR2 (50) := 'SCHONEN_PERSONEN';
v_errormsg VARCHAR2 (1000);
oracle_err_num NUMBER;
oracle_err_mes VARCHAR2 (200);
v_count_tot NUMBER (10) := 0;
v_perslid_key NUMBER (15);
CURSOR c IS
SELECT p.*
FROM prs_v_aanwezigperslid p, FAC_V_LCRAP_FE_VS_KEY_DATA u
WHERE p.prs_perslid_key = u.prs_perslid_key
AND ( TRUNC (p.prs_perslid_login) <
TRUNC (SYSDATE) - 365
AND p.prs_perslid_login IS NOT NULL)
UNION ALL
SELECT p.*
FROM prs_v_aanwezigperslid p, FAC_V_LCRAP_FE_VS_KEY_DATA u
WHERE p.prs_perslid_key = u.prs_perslid_key
AND ( TRUNC (p.prs_perslid_aanmaak) <
TRUNC (SYSDATE) - 365
AND p.prs_perslid_login IS NULL);
BEGIN
FOR rec IN c
LOOP
BEGIN
v_perslid_key := rec.prs_perslid_key;
prs.delete_perslid (1, v_perslid_key);
END;
END LOOP;
EXCEPTION
WHEN OTHERS
THEN
oracle_err_num := SQLCODE;
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
v_errormsg :=
v_errormsg
|| ' ORACLE (error '
|| oracle_err_num
|| '/'
|| oracle_err_mes
|| ')';
fac.writelog (c_applname,
'E',
v_errormsg,
'Daily achtergrond taak afgebroken!');
END;
END;
/
CREATE OR REPLACE PROCEDURE CEVA_DAILY
AS
v_errormsg VARCHAR2 (1000);
oracle_err_num NUMBER;
oracle_err_mes VARCHAR2 (200);
BEGIN
-- Dagelijks schonen personen die langer dan een jaar niet hebben ingelogd.
ceva.schonen_personen ();
END;
/
CREATE OR REPLACE VIEW ceva_v_mld_reports
(
melding_key,
melding_datum,
year,
quarter,
month,
week,
district_key,
district,
location_key,
location,
discipline_type,
discipline,
call,
status_key,
status_fac,
status
)
AS
SELECT m.mld_melding_key,
m.mld_melding_datum,
TO_NUMBER (TO_CHAR (m.mld_melding_datum, 'YYYY'))
AS year,
TO_NUMBER (TO_CHAR (m.mld_melding_datum, 'Q'))
AS quarter,
TO_NUMBER (TO_CHAR (m.mld_melding_datum, 'MM'))
AS month,
TO_NUMBER (
TO_CHAR (m.mld_melding_datum, 'IYYYWW'))
AS week,
d.alg_district_key,
d.alg_district_omschrijving,
l.alg_locatie_key,
l.alg_locatie_omschrijving,
sdisc.ins_srtdiscipline_omschrijving,
disc.ins_discipline_omschrijving,
sm.mld_stdmelding_omschrijving,
m.mld_melding_status,
ms.mld_statuses_omschrijving,
CASE
WHEN m.mld_melding_status IN (0, 2) THEN 'New'
WHEN m.mld_melding_status IN (3, 4, 7) THEN 'In progress'
WHEN m.mld_melding_status IN (5, 6, 99) THEN 'Closed'
WHEN m.mld_melding_status IN (1) THEN 'Rejected'
ELSE NULL
END
CASE
FROM mld_melding m,
alg_locatie l,
alg_district d,
mld_stdmelding sm,
ins_tab_discipline disc,
ins_srtdiscipline sdisc,
mld_statuses ms
WHERE l.alg_district_key = d.alg_district_key
AND m.mld_alg_locatie_key = l.alg_locatie_key
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
AND sm.mld_ins_discipline_key = disc.ins_discipline_key
AND disc.ins_srtdiscipline_key = sdisc.ins_srtdiscipline_key
AND m.mld_melding_status = ms.mld_statuses_key
ORDER BY m.mld_melding_key DESC;
CREATE OR REPLACE VIEW ceva_v_mld_report_lastweek
(
district,
location,
total,
new,
in_progress,
closed,
rejected
)
AS
SELECT d.alg_district_omschrijving,
l.alg_locatie_omschrijving,
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.melding_datum BETWEEN ( NEXT_DAY (TRUNC (SYSDATE),
'SUN')
- 14)
AND ( NEXT_DAY (TRUNC (SYSDATE),
'MON')
- 7)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.melding_datum BETWEEN ( NEXT_DAY (TRUNC (SYSDATE),
'SUN')
- 14)
AND ( NEXT_DAY (TRUNC (SYSDATE),
'MON')
- 7)
AND m.status_key IN (0, 2)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.melding_datum BETWEEN ( NEXT_DAY (TRUNC (SYSDATE),
'SUN')
- 14)
AND ( NEXT_DAY (TRUNC (SYSDATE),
'MON')
- 7)
AND m.status_key IN (3, 4, 7)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.melding_datum BETWEEN ( NEXT_DAY (TRUNC (SYSDATE),
'SUN')
- 14)
AND ( NEXT_DAY (TRUNC (SYSDATE),
'MON')
- 7)
AND m.status_key IN (5, 6, 99)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.melding_datum BETWEEN ( NEXT_DAY (TRUNC (SYSDATE),
'SUN')
- 14)
AND ( NEXT_DAY (TRUNC (SYSDATE),
'MON')
- 7)
AND m.status_key IN (1))
FROM alg_locatie l, alg_district d
WHERE l.alg_district_key = d.alg_district_key
AND l.alg_locatie_verwijder IS NULL;
CREATE OR REPLACE VIEW ceva_v_mld_report_ytd
(
district,
location,
total,
new,
in_progress,
closed,
rejected
)
AS
SELECT d.alg_district_omschrijving,
l.alg_locatie_omschrijving,
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.year = TO_CHAR (SYSDATE, 'YYYY')),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.year = TO_CHAR (SYSDATE, 'YYYY')
AND m.status_key IN (0, 2)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.year = TO_CHAR (SYSDATE, 'YYYY')
AND m.status_key IN (3, 4, 7)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.year = TO_CHAR (SYSDATE, 'YYYY')
AND m.status_key IN (5, 6, 99)),
(SELECT COUNT (*)
FROM ceva_v_mld_reports m
WHERE m.location_key = l.alg_locatie_key
AND m.year = TO_CHAR (SYSDATE, 'YYYY')
AND m.status_key IN (1))
FROM alg_locatie l, alg_district d
WHERE l.alg_district_key = d.alg_district_key
AND l.alg_locatie_verwijder IS NULL;
------ payload end ------
SET DEFINE OFF
BEGIN adm.systrackscriptId ('$Id$', 0); END;
/
COMMIT;
SET ECHO OFF
SPOOL OFF
SET DEFINE ON
PROMPT Logfile of this upgrade is: &fcltlogfile