860 lines
32 KiB
SQL
860 lines
32 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;
|
|
COLUMN fcltcusttxt NEW_VALUE fcltcusttxt NOPRINT;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL;
|
|
SPOOL &fcltlogfile
|
|
WHENEVER SQLERROR EXIT;
|
|
SELECT adm.checkscriptcust('&dbuser') AS fcltcusttxt FROM DUAL;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
---------------------------------------
|
|
PROMPT &fcltcusttxt
|
|
---------------------------------------
|
|
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,
|
|
a.bez_afspraak_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_count_del NUMBER (10);
|
|
|
|
v_perslid_key NUMBER (15);
|
|
|
|
CURSOR c IS
|
|
SELECT '['
|
|
|| TO_CHAR (p.prs_perslid_key)
|
|
|| '|'
|
|
|| p.prs_perslid_email
|
|
|| '|'
|
|
|| p.prs_perslid_naam
|
|
|| '] ' aanduiding,
|
|
p.prs_perslid_key,
|
|
COUNT (vp.prs_perslid_key) aant,
|
|
DECODE (p.prs_perslid_inactief, NULL, 0, 1) inactief
|
|
FROM prs_v_aanwezigperslid p,
|
|
FAC_V_LCRAP_FE_VS_KEY_DATA u,
|
|
prs_v_verplichting_keys vp
|
|
WHERE p.prs_perslid_key = u.prs_perslid_key
|
|
AND p.prs_perslid_key = vp.prs_perslid_key(+) -- Actuele verplichtingen?
|
|
AND ( TRUNC (p.prs_perslid_login) <
|
|
TRUNC (SYSDATE) - 365
|
|
AND p.prs_perslid_login IS NOT NULL)
|
|
GROUP BY '['
|
|
|| TO_CHAR (p.prs_perslid_key)
|
|
|| '|'
|
|
|| p.prs_perslid_email
|
|
|| '|'
|
|
|| p.prs_perslid_naam
|
|
|| '] ',
|
|
p.prs_perslid_key,
|
|
DECODE (p.prs_perslid_inactief, NULL, 0, 1)
|
|
UNION ALL
|
|
SELECT '['
|
|
|| TO_CHAR (p.prs_perslid_key)
|
|
|| '|'
|
|
|| p.prs_perslid_email
|
|
|| '|'
|
|
|| p.prs_perslid_naam
|
|
|| '] ' aanduiding,
|
|
p.prs_perslid_key,
|
|
COUNT (vp.prs_perslid_key) aant,
|
|
DECODE (p.prs_perslid_inactief, NULL, 0, 1) inactief
|
|
FROM prs_v_aanwezigperslid p,
|
|
FAC_V_LCRAP_FE_VS_KEY_DATA u,
|
|
prs_v_verplichting_keys vp
|
|
WHERE p.prs_perslid_key = u.prs_perslid_key
|
|
AND p.prs_perslid_key = vp.prs_perslid_key(+) -- Actuele verplichtingen?
|
|
AND ( TRUNC (p.prs_perslid_aanmaak) <
|
|
TRUNC (SYSDATE) - 365
|
|
AND p.prs_perslid_login IS NULL)
|
|
GROUP BY '['
|
|
|| TO_CHAR (p.prs_perslid_key)
|
|
|| '|'
|
|
|| p.prs_perslid_email
|
|
|| '|'
|
|
|| p.prs_perslid_naam
|
|
|| '] ',
|
|
p.prs_perslid_key,
|
|
DECODE (p.prs_perslid_inactief, NULL, 0, 1);
|
|
BEGIN
|
|
v_count_del := 0;
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
BEGIN
|
|
IF rec.aant = 0
|
|
THEN
|
|
v_errormsg := 'Fout schonen collega';
|
|
|
|
DELETE FROM
|
|
prs_collega
|
|
WHERE prs_perslid_key = rec.prs_perslid_key
|
|
OR prs_perslid_key_alt = rec.prs_perslid_key;
|
|
|
|
v_errormsg := 'Fout schonen persoon';
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_verwijder = SYSDATE
|
|
WHERE prs_perslid_key = rec.prs_perslid_key;
|
|
|
|
v_count_del := v_count_del + 1;
|
|
|
|
IF MOD (v_count_del, 1000) = 0
|
|
THEN
|
|
COMMIT;
|
|
END IF;
|
|
ELSE
|
|
fac.writelog (
|
|
'SCHONEN_PERSONEN',
|
|
'I',
|
|
rec.aanduiding
|
|
|| '/#Verplichtingen: '
|
|
|| TO_CHAR (rec.aant),
|
|
'Persoon niet geschoond');
|
|
|
|
IF rec.inactief = 0
|
|
THEN
|
|
v_errormsg := 'Fout inactiveren persoon';
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_inactief = SYSDATE
|
|
WHERE prs_perslid_key = rec.prs_perslid_key;
|
|
|
|
fac.trackaction ('PRSUPD',
|
|
rec.prs_perslid_key,
|
|
3, --Facilitor
|
|
SYSDATE,
|
|
'Persoon inactief gemaakt');
|
|
END IF;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN -- Kennelijk heeft persoon toch nog ernstige verplichtingen!
|
|
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 ('SCHONEN_PERSONEN',
|
|
'W',
|
|
rec.aanduiding || v_errormsg,
|
|
'Fout schonen persoon');
|
|
END;
|
|
END LOOP;
|
|
|
|
fac.writelog ('SCHONEN_PERSONEN',
|
|
'S',
|
|
'Personen/#geschoond: ' || TO_CHAR (v_count_del),
|
|
'');
|
|
COMMIT;
|
|
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,
|
|
COSTS
|
|
)
|
|
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, 'IYYYIW')) 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,
|
|
(SELECT fac.safe_to_number (costkmm.mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding costkmm, mld_kenmerk costkm
|
|
WHERE costkmm.mld_kenmerk_key = costkm.mld_kenmerk_key
|
|
AND costkm.mld_srtkenmerk_key = 162 -- Costs of the report
|
|
AND costkmm.mld_kenmerkmelding_verwijder IS NULL
|
|
AND m.mld_melding_key = costkmm.mld_melding_key) AS cost
|
|
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;
|
|
|
|
CREATE OR REPLACE VIEW CEVA_V_QRC_WERKPLEKKEN
|
|
(
|
|
HIDE_F_SORT,
|
|
LOCATIE_CODE,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW_NAAM,
|
|
FCLT_F_GEBOUW_OMSCHR,
|
|
FCLT_F_VERDIEPING,
|
|
ALG_RUIMTE_KEY,
|
|
FCLT_F_ALG_RUIMTE_NR,
|
|
INS_DEEL_KEY,
|
|
INS_DEEL_OMSCHR,
|
|
RES_DEEL_KEY,
|
|
RES_DEEL_OMSCHRIJVING,
|
|
FCLT_F_BOOKMARK,
|
|
FCLT_URL
|
|
)
|
|
AS
|
|
SELECT aog.alg_ruimte_nr,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_omschrijving,
|
|
aog.alg_gebouw_naam,
|
|
aog.alg_gebouw_naam,
|
|
aog.alg_verdieping_code,
|
|
aog.alg_ruimte_key,
|
|
aog.alg_ruimte_nr,
|
|
d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
rd.res_deel_key,
|
|
rd.res_deel_omschrijving,
|
|
b.fac_bookmark_id hide_f_bookmark_id,
|
|
'https://ceva.facilitor.nl/appl/pda/reserveringen.asp?urole=fe&qrc=1&restype=CV&act_key=30&res_deel_key='
|
|
|| res_deel_key url
|
|
FROM res_deel rd,
|
|
ins_deel d,
|
|
alg_v_onroerendgoed_gegevens aog,
|
|
alg_locatie l,
|
|
fac_bookmark b
|
|
WHERE rd.res_deel_verwijder IS NULL
|
|
AND UPPER (b.fac_bookmark_naam) IN ('QRC_WERKPLEK_RESERVERING')
|
|
AND COALESCE (b.fac_bookmark_expire, SYSDATE + 1) > SYSDATE
|
|
AND d.ins_deel_key = rd.res_ins_deel_key
|
|
AND d.ins_discipline_key = 181 -- Werkplekken
|
|
AND d.ins_deel_verwijder IS NULL
|
|
AND ( rd.res_deel_vervaldatum > SYSDATE
|
|
OR rd.res_deel_vervaldatum IS NULL)
|
|
AND d.ins_alg_ruimte_key = aog.alg_ruimte_key
|
|
AND l.alg_locatie_key = aog.alg_locatie_key;
|
|
|
|
CREATE OR REPLACE VIEW CEVA_V_EXPORT_BIJLAGEN_LOCATIES
|
|
(
|
|
TYPE,
|
|
LOCATIE,
|
|
GEBOUW,
|
|
VERDIEPING,
|
|
RUIMTE,
|
|
OBJECT_KEY,
|
|
OBJECT_ID,
|
|
OBJECT_OMSCHRIJVING,
|
|
MELDING,
|
|
CATEGORY,
|
|
CALL,
|
|
FAC_BIJLAGEN_AANMAAK,
|
|
FAC_BIJLAGEN_FILENAME,
|
|
FAC_BIJLAGEN_KEY,
|
|
FAC_BIJLAGEN_ZIPPATH,
|
|
CHECK_LENGTE
|
|
)
|
|
AS
|
|
SELECT 'locatie',
|
|
l.alg_locatie_omschrijving AS locatie,
|
|
NULL AS gebouw,
|
|
NULL AS verdieping,
|
|
NULL AS ruimte,
|
|
NULL AS object_key,
|
|
NULL AS object_id,
|
|
NULL AS object_omschrijving,
|
|
NULL AS melding,
|
|
NULL AS category,
|
|
NULL AS call,
|
|
b.fac_bijlagen_aanmaak,
|
|
b.fac_bijlagen_filename,
|
|
b.fac_bijlagen_key,
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename fac_bijlagen_zippath, -- Let op, padnaam kan/mag MAX 258 posities hebben (i.v.m. insuffficient memory)
|
|
LENGTH (
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename) check_lengte
|
|
FROM fac_v_bijlagen b, alg_locatie l
|
|
WHERE b.fac_bijlagen_verwijder IS NULL
|
|
AND b.fac_bijlagen_module = 'ALG'
|
|
AND b.fac_bijlagen_refkey = l.alg_locatie_key
|
|
UNION ALL
|
|
SELECT 'gebouw',
|
|
l.alg_locatie_omschrijving,
|
|
g.alg_gebouw_omschrijving,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
b.fac_bijlagen_aanmaak,
|
|
b.fac_bijlagen_filename,
|
|
b.fac_bijlagen_key,
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename fac_bijlagen_zippath, -- Let op, padnaam kan/mag MAX 258 posities hebben (i.v.m. insuffficient memory)
|
|
LENGTH (
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename) check_lengte
|
|
FROM fac_v_bijlagen b, alg_locatie l, alg_gebouw g
|
|
WHERE b.fac_bijlagen_verwijder IS NULL
|
|
AND l.alg_locatie_key = g.alg_locatie_key
|
|
AND b.fac_bijlagen_module = 'ALG'
|
|
AND b.fac_bijlagen_refkey = g.alg_gebouw_key
|
|
UNION ALL
|
|
SELECT 'verdieping',
|
|
l.alg_locatie_omschrijving,
|
|
g.alg_gebouw_omschrijving,
|
|
v.alg_verdieping_omschrijving,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
b.fac_bijlagen_aanmaak,
|
|
b.fac_bijlagen_filename,
|
|
b.fac_bijlagen_key,
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename fac_bijlagen_zippath, -- Let op, padnaam kan/mag MAX 258 posities hebben (i.v.m. insuffficient memory)
|
|
LENGTH (
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename) check_lengte
|
|
FROM fac_v_bijlagen b,
|
|
alg_locatie l,
|
|
alg_gebouw g,
|
|
alg_verdieping v
|
|
WHERE b.fac_bijlagen_verwijder IS NULL
|
|
AND l.alg_locatie_key = g.alg_locatie_key
|
|
AND g.alg_gebouw_key = v.alg_gebouw_key
|
|
AND b.fac_bijlagen_module = 'ALG'
|
|
AND b.fac_bijlagen_refkey = v.alg_verdieping_key
|
|
UNION ALL
|
|
SELECT 'ruimte',
|
|
l.alg_locatie_omschrijving,
|
|
g.alg_gebouw_omschrijving,
|
|
v.alg_verdieping_omschrijving,
|
|
r.alg_ruimte_nr,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
b.fac_bijlagen_aanmaak,
|
|
b.fac_bijlagen_filename,
|
|
b.fac_bijlagen_key,
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename fac_bijlagen_zippath, -- Let op, padnaam kan/mag MAX 258 posities hebben (i.v.m. insuffficient memory)
|
|
LENGTH (
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename) check_lengte
|
|
FROM fac_v_bijlagen b,
|
|
alg_locatie l,
|
|
alg_gebouw g,
|
|
alg_verdieping v,
|
|
alg_ruimte r
|
|
WHERE b.fac_bijlagen_verwijder IS NULL
|
|
AND l.alg_locatie_key = g.alg_locatie_key
|
|
AND g.alg_gebouw_key = v.alg_gebouw_key
|
|
AND v.alg_verdieping_key = r.alg_verdieping_key
|
|
AND b.fac_bijlagen_module = 'ALG'
|
|
AND b.fac_bijlagen_refkey = r.alg_ruimte_key
|
|
UNION ALL
|
|
SELECT 'melding',
|
|
l.alg_locatie_omschrijving,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
m.mld_melding_key,
|
|
disc.ins_discipline_omschrijving,
|
|
sm.mld_stdmelding_omschrijving,
|
|
b.fac_bijlagen_aanmaak,
|
|
b.fac_bijlagen_filename,
|
|
b.fac_bijlagen_key,
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename fac_bijlagen_zippath, -- Let op, padnaam kan/mag MAX 258 posities hebben (i.v.m. insuffficient memory)
|
|
LENGTH (
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename) check_lengte
|
|
FROM fac_v_bijlagen b,
|
|
alg_locatie l,
|
|
mld_melding m,
|
|
mld_stdmelding sm,
|
|
ins_tab_discipline disc
|
|
WHERE b.fac_bijlagen_verwijder IS NULL
|
|
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 b.fac_bijlagen_module = 'MLD'
|
|
AND b.fac_bijlagen_refkey = m.mld_melding_key
|
|
UNION ALL
|
|
SELECT 'object',
|
|
l.alg_locatie_omschrijving,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
d.ins_deel_opmerking,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
b.fac_bijlagen_aanmaak,
|
|
b.fac_bijlagen_filename,
|
|
b.fac_bijlagen_key,
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename fac_bijlagen_zippath, -- Let op, padnaam kan/mag MAX 258 posities hebben (i.v.m. insuffficient memory)
|
|
LENGTH (
|
|
b.fac_bijlagen_disk_directory
|
|
|| CHR (92)
|
|
|| b.fac_bijlagen_filename) check_lengte
|
|
FROM fac_v_bijlagen b, alg_locatie l, ins_deel d
|
|
WHERE b.fac_bijlagen_verwijder IS NULL
|
|
AND d.ins_alg_locatie_key = l.alg_locatie_key
|
|
AND b.fac_bijlagen_module = 'INS'
|
|
AND b.fac_bijlagen_refkey = d.ins_deel_key;
|
|
|
|
------ 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 |