1328 lines
49 KiB
SQL
1328 lines
49 KiB
SQL
-- Script containing customer specific configuration sql statements for Essent: Arcadis Aqumen Facility Management
|
|
-- (c) 2005-2007 SG facilitor bv
|
|
-- $Revision$
|
|
-- $Id$
|
|
--
|
|
-- Support: +31 53 4800700
|
|
|
|
DEFINE thisfile = 'AAES.SQL'
|
|
DEFINE dbuser = '^AAES'
|
|
|
|
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 ------
|
|
|
|
-- script om dagelijks terugkerende scripts aan te roepen.
|
|
CREATE OR REPLACE PROCEDURE aaes_select_daily_task (p_applname IN VARCHAR2, p_applrun IN VARCHAR2)
|
|
AS
|
|
BEGIN
|
|
aaxx_daily_task (p_applname, p_applrun);
|
|
-- aaes_export_lease_aanvraag ('LEASE_AANVRAAG');
|
|
-- aaes_set_budgethouder();
|
|
|
|
END;
|
|
/
|
|
|
|
-- budgettracker overrules
|
|
CREATE OR REPLACE VIEW aaes_v_export_budget_tracker (RESULT, result_order) AS SELECT RESULT, result_order FROM aaxx_v_export_budget_tracker;
|
|
|
|
-- export overrules
|
|
-- exact - gaat direct naar aaxx
|
|
-- Leverancier overrulles
|
|
CREATE OR REPLACE PROCEDURE aaes_import_opdrstat_strukton (
|
|
p_import_key IN NUMBER)
|
|
AS
|
|
BEGIN
|
|
aaxx_import_opdrstat_strukton (p_import_key);
|
|
END aaes_import_opdrstat_strukton;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE aaes_update_opdrstat_strukton (
|
|
p_import_key IN NUMBER)
|
|
AS
|
|
BEGIN
|
|
aaxx_update_opdrstat_strukton (p_import_key);
|
|
END aaes_update_opdrstat_strukton;
|
|
/
|
|
|
|
|
|
-- exact verkoop
|
|
CREATE OR REPLACE VIEW aaes_v_export_exact_verkoop (RESULT, result_order) AS SELECT RESULT, result_order FROM aaxx_v_export_exact_verkoop;
|
|
CREATE OR REPLACE PROCEDURE aaes_select_exact_verkoop (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_select_exact_verkoop(p_applname, p_applrun, to_char(sysdate, 'yyyy'), 'CORE');
|
|
END;
|
|
/
|
|
CREATE OR REPLACE PROCEDURE aaes_export_exact_verkoop (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_export_exact_verkoop(p_applname, p_applrun, p_filedir, p_filename, to_char(sysdate, 'yyyy'), 'CORE');
|
|
END;
|
|
/
|
|
|
|
-- exact verkoop over het vorige jaar
|
|
CREATE OR REPLACE VIEW aaes_v_export_exact_verkoop_vj (RESULT, result_order) AS SELECT RESULT, result_order FROM aaxx_v_export_exact_verkoop;
|
|
CREATE OR REPLACE PROCEDURE aaes_select_exact_verkoop_vj (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_select_exact_verkoop(p_applname, p_applrun, to_char(to_number(to_char(sysdate, 'yyyy'))-1), 'CORE');
|
|
END;
|
|
/
|
|
CREATE OR REPLACE PROCEDURE aaes_export_exact_verkoop_vj (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_export_exact_verkoop(p_applname, p_applrun, p_filedir, p_filename, to_char(to_number(to_char(sysdate, 'yyyy'))-1), 'CORE');
|
|
END;
|
|
/
|
|
|
|
-- exact verkoop - PROJECTEN CSV
|
|
CREATE OR REPLACE VIEW aaes_v_export_exact_verkoop_p (RESULT, result_order) AS SELECT RESULT, result_order FROM aaxx_v_export_exact_verkoop;
|
|
CREATE OR REPLACE PROCEDURE aaes_select_exact_verkoop_p (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_select_exact_verkoop(p_applname, p_applrun, to_char(sysdate, 'yyyy'), 'PROJECT');
|
|
END;
|
|
/
|
|
CREATE OR REPLACE PROCEDURE aaes_export_exact_verkoop_p (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_export_exact_verkoop(p_applname, p_applrun, p_filedir, p_filename, to_char(sysdate, 'yyyy'), 'PROJECT');
|
|
END;
|
|
/
|
|
|
|
-- exact verkoop over het vorige jaar - PROJECTEN CSV
|
|
CREATE OR REPLACE VIEW aaes_v_export_exact_verkoop_vj_p (RESULT, result_order) AS SELECT RESULT, result_order FROM aaxx_v_export_exact_verkoop;
|
|
CREATE OR REPLACE PROCEDURE aaes_select_exact_verkoop_vj_p (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_select_exact_verkoop(p_applname, p_applrun, to_char(to_number(to_char(sysdate, 'yyyy'))-1), 'PROJECT');
|
|
END;
|
|
/
|
|
CREATE OR REPLACE PROCEDURE aaes_export_exact_verkoop_vj_p (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_export_exact_verkoop(p_applname, p_applrun, p_filedir, p_filename, to_char(to_number(to_char(sysdate, 'yyyy'))-1), 'PROJECT');
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE aaes_export_bundel_catering (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
c_catmld_uitvoertijd mld_stdmelding.mld_stdmelding_t_uitvoertijd%TYPE := MLD_T_UITVOERTIJD(2, 'D');
|
|
v_errormsg VARCHAR (200);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_laatste_export DATE;
|
|
v_mld_melding_key NUMBER;
|
|
v_prs_bedrijf_key NUMBER;
|
|
v_alg_locatie_key NUMBER;
|
|
v_alg_gebouw_key NUMBER;
|
|
v_prs_dienst_key NUMBER;
|
|
v_prs_kostenplaats_key NUMBER;
|
|
v_mld_opdr_bedrijfopdr_volgnr NUMBER;
|
|
v_aanvrager NUMBER;
|
|
v_mld_workorder_key NUMBER;
|
|
v_mld_stdmelding_key NUMBER;
|
|
v_date DATE;
|
|
v_date_check DATE;
|
|
v_count NUMBER;
|
|
v_total NUMBER(10,2);
|
|
BEGIN
|
|
-- Facilitor
|
|
v_aanvrager := 4;
|
|
-- Essent kostenplaats key
|
|
v_prs_kostenplaats_key := 510;
|
|
-- stdmelding key voor recharge
|
|
v_mld_stdmelding_key := 981;
|
|
-- key van opdrachttype workorder
|
|
v_mld_workorder_key := 1;
|
|
-- key voor de locatie van de melding
|
|
v_alg_locatie_key := 225;
|
|
-- key voor de gebouw van de melding
|
|
v_alg_gebouw_key := 3969;
|
|
-- key van Eurest
|
|
v_prs_bedrijf_key := 797;
|
|
|
|
v_errormsg := 'Bepaal einddatum';
|
|
|
|
-- wat is de eerste dag van de huidige maand
|
|
v_date := to_date(to_char(sysdate, 'yyyymm')||'01','yyyymmdd');
|
|
|
|
|
|
SELECT count(mld_opdr_key)
|
|
INTO v_count
|
|
FROM mld_opdr
|
|
WHERE mld_opdr_omschrijving = 'Catering factuur tot: ' || to_char(v_date, 'dd-mm-yyyy');
|
|
|
|
SELECT COALESCE(SUM (res_rsv_artikel_prijs),0)
|
|
INTO v_total
|
|
FROM res_rsv_artikel rra
|
|
WHERE rra.res_rsv_artikel_verwijder IS NULL
|
|
AND rra.res_status_bo_key = 5 -- geleverd.
|
|
AND rra.res_rsv_artikel_levering < v_date;
|
|
|
|
IF v_count > 0 THEN
|
|
fac.writelog (p_applname, 'E', 'Catering export is al eerder uitgevoerd.',
|
|
'Controleer opdrachten met datum: ' || to_char(v_date, 'dd-mm-yyyy'));
|
|
ELSIF v_total = 0 THEN
|
|
fac.writelog (p_applname, 'W', 'Er is deze maand niets te factureren',
|
|
'Controleer of de catering wel afgemeld is');
|
|
ELSE
|
|
v_errormsg := 'Aanpassen kostenplaatsen';
|
|
-- vul de kostenplaats van reserveringen die per abuis geen kostenplaats hebben.
|
|
UPDATE res_rsv_ruimte rrr
|
|
SET prs_kostenplaats_key =
|
|
(SELECT a.prs_kostenplaats_key
|
|
FROM prs_perslid p, prs_afdeling a
|
|
WHERE rrr.res_rsv_ruimte_host_key = p.prs_perslid_key
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key)
|
|
WHERE rrr.prs_kostenplaats_key IS NULL;
|
|
|
|
-- maak een melding aan voor deze maand
|
|
|
|
v_errormsg := 'Aanmaken catering melding';
|
|
BEGIN
|
|
INSERT INTO mld_melding
|
|
(
|
|
mld_melding_omschrijving,
|
|
prs_perslid_key,
|
|
prs_kostenplaats_key,
|
|
mld_stdmelding_key,
|
|
mld_alg_locatie_key,
|
|
mld_alg_onroerendgoed_keys,
|
|
mld_melding_einddatum,
|
|
mld_melding_datum,
|
|
mld_melding_t_uitvoertijd,
|
|
mld_meldbron_key,
|
|
mld_melding_module,
|
|
mld_melding_spoed
|
|
)
|
|
VALUES (
|
|
'Catering factuur boekingen tot ' || to_char(v_date, 'dd-mm-yyyy'),
|
|
v_aanvrager,
|
|
v_prs_kostenplaats_key,
|
|
v_mld_stdmelding_key,
|
|
v_alg_locatie_key,
|
|
v_alg_gebouw_key,
|
|
v_date-1,
|
|
add_months(v_date, -1),
|
|
c_catmld_uitvoertijd,
|
|
5,
|
|
'MLD',
|
|
3
|
|
) RETURNING mld_melding_key INTO v_mld_melding_key;
|
|
|
|
BEGIN mld.setmeldingstatus(v_mld_melding_key, 2, v_aanvrager); END;
|
|
BEGIN mld.setmeldingstatus(v_mld_melding_key, 4, v_aanvrager); END;
|
|
UPDATE mld_melding SET mld_melding_behandelaar_key= v_aanvrager WHERE mld_melding_key = v_mld_melding_key;
|
|
END;
|
|
|
|
-- aanmaken opdracht
|
|
|
|
|
|
BEGIN
|
|
v_mld_opdr_bedrijfopdr_volgnr := mld.BepaalOpdrMeldingVolgnr (v_mld_melding_key);
|
|
|
|
v_errormsg := 'Maak opdracht aan om factuur van cateraar te matchen';
|
|
-- maak opdracht aan om cateringfactuur van leverancier te matchen
|
|
INSERT INTO mld_opdr (mld_melding_key
|
|
, prs_kostenplaats_key
|
|
, mld_statusopdr_key
|
|
, mld_typeopdr_key
|
|
, prs_perslid_key
|
|
, mld_uitvoerende_keys
|
|
, mld_opdr_datumbegin
|
|
, mld_opdr_einddatum
|
|
, mld_opdr_module
|
|
, mld_opdr_omschrijving
|
|
, mld_opdr_materiaal
|
|
, mld_opdr_kosten
|
|
, mld_opdr_bedrijfopdr_volgnr)
|
|
VALUES
|
|
( v_mld_melding_key
|
|
, v_prs_kostenplaats_key
|
|
, 5 -- uitgegeven
|
|
, v_mld_workorder_key
|
|
, v_aanvrager
|
|
, v_prs_bedrijf_key
|
|
, v_date-1
|
|
, FAC.DatumTijdPlusUitvoerTijd(sysdate, 1, 'DAGEN')
|
|
, 'MLD'
|
|
, 'Catering factuur tot: ' || to_char(v_date, 'dd-mm-yyyy')
|
|
, v_total
|
|
, v_total
|
|
, v_mld_opdr_bedrijfopdr_volgnr);
|
|
|
|
UPDATE res_rsv_artikel rra
|
|
SET res_rsv_artikel_verwerkt = SYSDATE,
|
|
res_status_bo_key = 6
|
|
WHERE rra.res_rsv_artikel_verwijder IS NULL
|
|
AND rra.res_status_bo_key = 5 -- geleverd.
|
|
AND rra.res_rsv_artikel_levering < v_date;
|
|
|
|
v_errormsg := 'Update melding status';
|
|
MLD.updatemeldingstatus (v_mld_melding_key, 0, v_aanvrager); -- Facilitor
|
|
|
|
EXCEPTION WHEN OTHERS THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
|
v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.writelog (p_applname, 'E', v_errormsg, '');
|
|
END;
|
|
END IF;
|
|
COMMIT;
|
|
END;
|
|
/
|
|
|
|
|
|
|
|
-- exact projecturen (XML)
|
|
CREATE OR REPLACE VIEW aaes_v_export_exact_uren (result, result_order)
|
|
AS SELECT result, result_order FROM aaxx_v_export_exact_uren_xml;
|
|
CREATE OR REPLACE PROCEDURE aaes_select_exact_uren (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_select_exact_uren_xml(p_applname, p_applrun, '');
|
|
END;
|
|
/
|
|
|
|
-- verwerk exact projecturen (XML)
|
|
CREATE OR REPLACE PROCEDURE aaes_export_verwerk_exact_uren (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
aaxx_export_verwerk_exact_uren(p_applname, p_applrun, p_filedir, p_filename, '');
|
|
END;
|
|
/
|
|
|
|
|
|
|
|
--------------------------------
|
|
-- import contractorders
|
|
--------------------------------
|
|
CREATE OR REPLACE PROCEDURE aaes_import_contract (
|
|
p_import_key IN NUMBER
|
|
) IS
|
|
BEGIN
|
|
aaxx_import_contract (p_import_key);
|
|
END aaes_import_contract;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE aaes_update_contract (p_import_key IN NUMBER)
|
|
AS
|
|
BEGIN
|
|
aaxx_update_contract (p_import_key);
|
|
END aaes_update_contract;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE aaes_import_ruimte (p_import_key IN NUMBER)
|
|
AS
|
|
BEGIN
|
|
aaxx_import_ruimte(p_import_key);
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE aaes_update_ruimte (p_import_key IN NUMBER)
|
|
AS
|
|
BEGIN
|
|
aaxx_update_ruimte(p_import_key);
|
|
END;
|
|
/
|
|
|
|
|
|
-- eigen afdelingstructuur omdat Enexis meer dan 5 niveaus kent.
|
|
CREATE OR REPLACE VIEW aaes_v_afdeling
|
|
(
|
|
prs_bedrijf_key,
|
|
prs_afdeling_key,
|
|
prs_afdeling_parentkey
|
|
)
|
|
AS
|
|
SELECT a.prs_bedrijf_key, a.prs_afdeling_key, kl.prs_afdeling_parentkey
|
|
FROM prs_afdeling a,
|
|
(SELECT prs_link_key prs_afdeling_key,
|
|
prs_kenmerklink_waarde prs_afdeling_parentkey
|
|
FROM prs_kenmerklink
|
|
WHERE prs_kenmerk_key = 1020) kl
|
|
WHERE a.prs_afdeling_key = kl.prs_afdeling_key(+);
|
|
|
|
CREATE OR REPLACE VIEW aaes_v_afdeling_boom
|
|
(
|
|
niveau,
|
|
prs_bedrijf_key,
|
|
prs_afdeling_key,
|
|
prs_afdeling_key1,
|
|
prs_afdeling_key2,
|
|
prs_afdeling_key3,
|
|
prs_afdeling_key4,
|
|
prs_afdeling_key5,
|
|
prs_afdeling_key6,
|
|
prs_afdeling_key7,
|
|
prs_afdeling_key8,
|
|
prs_afdeling_key9,
|
|
prs_afdeling_key10
|
|
)
|
|
AS
|
|
SELECT '1' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a1.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1
|
|
WHERE a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '2' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a2.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1, aaes_v_afdeling a2
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '3' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a3.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1, aaes_v_afdeling a2, aaes_v_afdeling a3
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '4' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a4.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '5' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a5.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
a5.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4,
|
|
aaes_v_afdeling a5
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a5.prs_afdeling_parentkey = a4.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '6' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a6.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
a5.prs_afdeling_key,
|
|
a6.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4,
|
|
aaes_v_afdeling a5,
|
|
aaes_v_afdeling a6
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a5.prs_afdeling_parentkey = a4.prs_afdeling_key
|
|
AND a6.prs_afdeling_parentkey = a5.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '7' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a7.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
a5.prs_afdeling_key,
|
|
a6.prs_afdeling_key,
|
|
a7.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4,
|
|
aaes_v_afdeling a5,
|
|
aaes_v_afdeling a6,
|
|
aaes_v_afdeling a7
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a5.prs_afdeling_parentkey = a4.prs_afdeling_key
|
|
AND a6.prs_afdeling_parentkey = a5.prs_afdeling_key
|
|
AND a7.prs_afdeling_parentkey = a6.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '8' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a8.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
a5.prs_afdeling_key,
|
|
a6.prs_afdeling_key,
|
|
a7.prs_afdeling_key,
|
|
a8.prs_afdeling_key,
|
|
TO_NUMBER (NULL),
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4,
|
|
aaes_v_afdeling a5,
|
|
aaes_v_afdeling a6,
|
|
aaes_v_afdeling a7,
|
|
aaes_v_afdeling a8
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a5.prs_afdeling_parentkey = a4.prs_afdeling_key
|
|
AND a6.prs_afdeling_parentkey = a5.prs_afdeling_key
|
|
AND a7.prs_afdeling_parentkey = a6.prs_afdeling_key
|
|
AND a8.prs_afdeling_parentkey = a7.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '9' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a9.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
a5.prs_afdeling_key,
|
|
a6.prs_afdeling_key,
|
|
a7.prs_afdeling_key,
|
|
a8.prs_afdeling_key,
|
|
a9.prs_afdeling_key,
|
|
TO_NUMBER (NULL)
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4,
|
|
aaes_v_afdeling a5,
|
|
aaes_v_afdeling a6,
|
|
aaes_v_afdeling a7,
|
|
aaes_v_afdeling a8,
|
|
aaes_v_afdeling a9
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a5.prs_afdeling_parentkey = a4.prs_afdeling_key
|
|
AND a6.prs_afdeling_parentkey = a5.prs_afdeling_key
|
|
AND a7.prs_afdeling_parentkey = a6.prs_afdeling_key
|
|
AND a8.prs_afdeling_parentkey = a7.prs_afdeling_key
|
|
AND a9.prs_afdeling_parentkey = a8.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL
|
|
UNION
|
|
SELECT '10' niveau,
|
|
a1.prs_bedrijf_key,
|
|
a10.prs_afdeling_key,
|
|
a1.prs_afdeling_key,
|
|
a2.prs_afdeling_key,
|
|
a3.prs_afdeling_key,
|
|
a4.prs_afdeling_key,
|
|
a5.prs_afdeling_key,
|
|
a6.prs_afdeling_key,
|
|
a7.prs_afdeling_key,
|
|
a8.prs_afdeling_key,
|
|
a9.prs_afdeling_key,
|
|
a10.prs_afdeling_key
|
|
FROM aaes_v_afdeling a1,
|
|
aaes_v_afdeling a2,
|
|
aaes_v_afdeling a3,
|
|
aaes_v_afdeling a4,
|
|
aaes_v_afdeling a5,
|
|
aaes_v_afdeling a6,
|
|
aaes_v_afdeling a7,
|
|
aaes_v_afdeling a8,
|
|
aaes_v_afdeling a9,
|
|
aaes_v_afdeling a10
|
|
WHERE a2.prs_afdeling_parentkey = a1.prs_afdeling_key
|
|
AND a3.prs_afdeling_parentkey = a2.prs_afdeling_key
|
|
AND a4.prs_afdeling_parentkey = a3.prs_afdeling_key
|
|
AND a5.prs_afdeling_parentkey = a4.prs_afdeling_key
|
|
AND a6.prs_afdeling_parentkey = a5.prs_afdeling_key
|
|
AND a7.prs_afdeling_parentkey = a6.prs_afdeling_key
|
|
AND a8.prs_afdeling_parentkey = a7.prs_afdeling_key
|
|
AND a9.prs_afdeling_parentkey = a8.prs_afdeling_key
|
|
AND a10.prs_afdeling_parentkey = a9.prs_afdeling_key
|
|
AND a1.prs_afdeling_parentkey IS NULL;
|
|
|
|
|
|
CREATE OR REPLACE VIEW aaes_v_leidinggevende_afd
|
|
(
|
|
prs_afdeling_key,
|
|
prs_perslid_key_leid
|
|
)
|
|
AS
|
|
SELECT prs_afdeling_key,
|
|
COALESCE (al10, COALESCE (al9, COALESCE (al8, COALESCE (al7, COALESCE (al6, COALESCE (al5, COALESCE (al4, COALESCE (al3, COALESCE (al2, al1)))))))))
|
|
FROM (SELECT a.prs_afdeling_key,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key1 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al1,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key2 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al2,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key3 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al3,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key4 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al4,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key5 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al5,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key6 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al6,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key7 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al7,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key8 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al8,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key9 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al9,
|
|
(SELECT kl.prs_kenmerklink_waarde
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key10 = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al10
|
|
FROM aaes_v_afdeling_boom a);
|
|
|
|
CREATE OR REPLACE VIEW aaes_v_leidinggevende
|
|
(
|
|
prs_perslid_key,
|
|
prs_afdeling_key,
|
|
prs_perslid_key_leid,
|
|
niveau2,
|
|
niveau1
|
|
)
|
|
AS
|
|
SELECT prs_perslid_key,
|
|
prs_afdeling_key,
|
|
COALESCE (al10, COALESCE (al9, COALESCE (al8, COALESCE (al7, COALESCE (al6, COALESCE (al5, COALESCE (al4, COALESCE (al3, COALESCE (al2, al1))))))))),
|
|
al2,
|
|
al1
|
|
FROM (SELECT prs_perslid_key,
|
|
p.prs_afdeling_key,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key1 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al1,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key2 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al2,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key3 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al3,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key4 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al4,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key5 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al5,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key6 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al6,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key7 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al7,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key8 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al8,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key9 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al9,
|
|
(SELECT FAC.safe_to_number(kl.prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE a.prs_afdeling_key10 = kl.prs_link_key
|
|
AND kl.prs_kenmerklink_waarde <> p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1000)
|
|
al10
|
|
FROM prs_perslid p, aaes_v_afdeling_boom a
|
|
WHERE p.prs_afdeling_key = a.prs_afdeling_key);
|
|
|
|
|
|
CREATE OR REPLACE VIEW aaes_v_rap_fiat_leiding
|
|
(
|
|
NUMMER,
|
|
DATUM,
|
|
VAKGROEP,
|
|
MELDING,
|
|
MELDING_TEKST,
|
|
MELDER,
|
|
MLD_STATUSES_KEY,
|
|
STATUS,
|
|
GEPLANDE_EINDDATUM,
|
|
HIDE_F_MLD_MELDING_KEY,
|
|
MLD_STDMELDING_KEY,
|
|
FCLT_3D_USER_KEY
|
|
)
|
|
AS
|
|
SELECT DECODE (COALESCE (sd.ins_srtdiscipline_prefix, ''),
|
|
'', '',
|
|
sd.ins_srtdiscipline_prefix)
|
|
|| TO_CHAR (m.mld_melding_key)
|
|
nummer,
|
|
TO_CHAR (m.mld_melding_datum, 'dd-mm-yyyy') datum,
|
|
DECODE (COALESCE (sd.ins_srtdiscipline_prefix, ''),
|
|
'', '',
|
|
sd.ins_srtdiscipline_prefix || '-')
|
|
|| td.ins_discipline_omschrijving
|
|
vakgroep,
|
|
sm.mld_stdmelding_omschrijving melding,
|
|
'Prive adres: '
|
|
|| (SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 321)
|
|
|| CHR (13)
|
|
|| 'Postcode / Woonplaats: '
|
|
|| (SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 322)
|
|
|| CHR (13)
|
|
|| 'Huidige merk en kenteken: '
|
|
|| (SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 323)
|
|
|| CHR (13)
|
|
|| 'Prognose zakelijk per jaar: '
|
|
|| (SELECT fac_usrdata_omschr
|
|
FROM fac_usrdata ud, mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE fac.safe_to_number (mld_kenmerkmelding_waarde) =
|
|
fac_usrdata_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 301)
|
|
|| CHR (13)
|
|
|| 'Prognose prive per jaar: '
|
|
|| (SELECT fac_usrdata_omschr
|
|
FROM fac_usrdata ud, mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE fac.safe_to_number (mld_kenmerkmelding_waarde) =
|
|
fac_usrdata_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 302)
|
|
|| CHR (13)
|
|
|| 'Prognose woon- werk per jaar: '
|
|
|| (SELECT fac_usrdata_omschr
|
|
FROM fac_usrdata ud, mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE fac.safe_to_number (mld_kenmerkmelding_waarde) =
|
|
fac_usrdata_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 303)
|
|
|| CHR (13)
|
|
|| 'Voorstel categorieindeling: '
|
|
|| (SELECT fac_usrdata_omschr
|
|
FROM fac_usrdata ud, mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE fac.safe_to_number (mld_kenmerkmelding_waarde) =
|
|
fac_usrdata_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_srtkenmerk_key = 305)
|
|
|| CHR (13)
|
|
|| 'Omschrijving: '
|
|
|| SUBSTR(mld_melding_omschrijving, 1, 2000),
|
|
pf.prs_perslid_naam_full melder,
|
|
s.mld_statuses_key,
|
|
s.mld_statuses_omschrijving status,
|
|
m.mld_melding_einddatum geplande_einddatum,
|
|
m.mld_melding_key mld_key,
|
|
sm.mld_stdmelding_key,
|
|
l.prs_perslid_key_leid leidinggevende
|
|
FROM mld_melding m,
|
|
mld_statuses s,
|
|
mld_stdmelding sm,
|
|
ins_tab_discipline td,
|
|
ins_srtdiscipline sd,
|
|
prs_v_perslid_fullnames_all pf,
|
|
aaes_v_leidinggevende l
|
|
WHERE m.mld_melding_status IN (2, 3, 4) -- Te behandelen! + in behandeling.
|
|
AND m.mld_melding_status = s.mld_statuses_key
|
|
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND sm.mld_ins_discipline_key = td.ins_discipline_key
|
|
AND sm.mld_stdmelding_key = 806 -- Goedkeuring door leidinggevende
|
|
AND td.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
|
AND m.prs_perslid_key = pf.prs_perslid_key
|
|
AND pf.prs_perslid_key = l.prs_perslid_key;
|
|
|
|
|
|
CREATE OR REPLACE VIEW aaes_v_hr_adviseur
|
|
(
|
|
prs_perslid_key,
|
|
prs_perslid_naam_full
|
|
)
|
|
AS
|
|
SELECT pf.prs_perslid_key, pf.prs_perslid_naam_full
|
|
FROM prs_v_perslid_fullnames pf, fac_gebruikersgroep gg
|
|
WHERE pf.prs_perslid_key = gg.prs_perslid_key AND gg.fac_groep_key = 181;
|
|
|
|
|
|
CREATE OR REPLACE VIEW aaes_v_noti_leaseaanvraag (
|
|
code,
|
|
sender,
|
|
receiver,
|
|
text,
|
|
key,
|
|
xkey
|
|
)
|
|
AS
|
|
-- 1e leidinggevende notificeren
|
|
SELECT 'CUST01',
|
|
NULL,
|
|
fac.safe_to_number (l.prs_perslid_key_leid),
|
|
'Niet per e-mail te fiatteren',
|
|
mld_melding_key,
|
|
NULL
|
|
FROM mld_melding m, aaes_v_leidinggevende l
|
|
WHERE m.prs_perslid_key = l.prs_perslid_key
|
|
AND m.mld_stdmelding_key = 806
|
|
AND m.mld_melding_datum > SYSDATE - 1
|
|
AND m.mld_melding_status IN (2, 3, 4)
|
|
UNION ALL
|
|
-- HR adviseur notificeren
|
|
SELECT 'MLD2BO',
|
|
NULL,
|
|
fac.safe_to_number (km.mld_kenmerkmelding_waarde),
|
|
'Facilitor: Er is een nieuwe melding ' || sd.ins_srtdiscipline_prefix || m.mld_melding_key || ' (' || d.ins_discipline_omschrijving || '/' || std.mld_stdmelding_omschrijving || ')',
|
|
m.mld_melding_key,
|
|
NULL
|
|
FROM mld_melding m, mld_kenmerkmelding km, mld_stdmelding std, ins_tab_discipline d, ins_srtdiscipline sd
|
|
WHERE m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
|
AND m.mld_melding_key = km.mld_melding_key
|
|
AND km.mld_kenmerk_key = 1021 -- Gewenste HR adviseur
|
|
AND m.mld_stdmelding_key = 805 -- Aanvraag formulier leaseauto
|
|
AND m.mld_melding_datum > SYSDATE - 1
|
|
AND m.mld_melding_status IN (2, 3, 4);
|
|
|
|
-- export leaseopdracht naar leasemaatschappij
|
|
CREATE OR REPLACE PROCEDURE aaes_export_lease_aanvraag (
|
|
p_applname IN VARCHAR2
|
|
)
|
|
AS
|
|
CURSOR c
|
|
IS
|
|
SELECT m.mld_melding_key,
|
|
m.prs_kostenplaats_key,
|
|
m.mld_melding_omschrijving,
|
|
MAX (bdl.prs_bedrijf_key) prs_bedrijf_key
|
|
FROM mld_melding m,
|
|
mld_stdmelding std,
|
|
prs_dienst d,
|
|
prs_bedrijfdienstlocatie bdl
|
|
WHERE m.mld_stdmelding_key = 807 -- goedkeuring HR manager
|
|
AND m.mld_melding_status = 5 -- afgemeld
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.prs_dienst_key = bdl.prs_dienst_key
|
|
AND NOT EXISTS (SELECT mld_melding_key
|
|
FROM mld_opdr o
|
|
WHERE mld_melding_key = m.mld_melding_key)
|
|
GROUP BY mld_melding_key, m.prs_kostenplaats_key, mld_melding_omschrijving;
|
|
|
|
CURSOR co
|
|
IS
|
|
SELECT mld_opdr_key
|
|
FROM mld_melding m, mld_opdr o
|
|
WHERE m.mld_melding_key = o.mld_melding_key
|
|
AND m.mld_stdmelding_key = 807
|
|
AND o.mld_statusopdr_key = 5
|
|
AND o.mld_opdr_verzonden IS NOT NULL;
|
|
|
|
CURSOR cl
|
|
IS
|
|
SELECT mld_melding_key
|
|
FROM (SELECT fac.safe_to_number (l.prs_perslid_key_leid) leidinggevende,
|
|
mld_melding_key
|
|
FROM mld_melding m, aaes_v_leidinggevende l
|
|
WHERE m.prs_perslid_key = l.prs_perslid_key
|
|
AND m.mld_stdmelding_key = 806
|
|
AND m.mld_melding_status IN (2, 3, 4))
|
|
WHERE leidinggevende IS NULL;
|
|
|
|
|
|
BEGIN
|
|
|
|
FOR rec IN cl -- hangende meldingen die geen leidinggevende meer hebben.
|
|
LOOP
|
|
BEGIN
|
|
MLD.setmeldingstatus(rec.mld_melding_key, 4, 4); -- accepteren door facilitor
|
|
MLD.setmeldingstatus(rec.mld_melding_key, 5, 4); -- afmelden door facilitor
|
|
MLD.mld_nextworkflowstep (rec.mld_melding_key, 1); -- Succes en trap de volgende workflow stap af.
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
fac.writelog (p_applname
|
|
, 'E'
|
|
, 'OTHERS (error ' || SQLCODE || '/' || SUBSTR (SQLERRM, 1, 100) || ')'
|
|
, 'Fout bij afhandelen van melding: ' || rec.mld_melding_key);
|
|
|
|
END;
|
|
END LOOP;
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
BEGIN
|
|
INSERT INTO mld_opdr (mld_melding_key
|
|
, prs_kostenplaats_key
|
|
, mld_statusopdr_key
|
|
, mld_typeopdr_key
|
|
, prs_perslid_key
|
|
, mld_uitvoerende_keys
|
|
, mld_opdr_datumbegin
|
|
, mld_opdr_einddatum
|
|
, mld_opdr_module
|
|
, mld_opdr_omschrijving
|
|
, mld_opdr_bedrijfopdr_volgnr
|
|
, mld_opdr_teverzenden)
|
|
VALUES ( rec.mld_melding_key
|
|
, rec.prs_kostenplaats_key
|
|
, 5 -- uitgegeven
|
|
, 2 -- docket
|
|
, 4 -- facilitor
|
|
, rec.prs_bedrijf_key
|
|
, SYSDATE
|
|
, FAC.DatumTijdPlusUitvoerTijd (SYSDATE, 1, 'DAGEN')
|
|
, 'MLD'
|
|
, rec.mld_melding_omschrijving
|
|
, 1
|
|
, 1);
|
|
|
|
-- update melding status is niet nodig omdat de melding al afgemeld is.
|
|
-- MLD.updatemeldingstatus (rec.mld_melding_key, 0, 4); -- facilitor
|
|
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
fac.writelog (p_applname
|
|
, 'E'
|
|
, 'OTHERS (error ' || SQLCODE || '/' || SUBSTR (SQLERRM, 1, 100) || ')'
|
|
, 'Fout bij aanmaken opdracht: ' || rec.mld_melding_key);
|
|
|
|
END;
|
|
END LOOP;
|
|
|
|
FOR rec IN co
|
|
LOOP
|
|
BEGIN
|
|
mld.setopdrachtstatus(rec.mld_opdr_key, 6, 4); -- afgemeld, facilitor
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
fac.writelog (p_applname
|
|
, 'E'
|
|
, 'OTHERS (error ' || SQLCODE || '/' || SUBSTR (SQLERRM, 1, 100) || ')'
|
|
, 'Fout bij afmelden opdracht: ' || rec.mld_opdr_key);
|
|
END;
|
|
END LOOP;
|
|
END aaes_export_lease_aanvraag;
|
|
/
|
|
|
|
|
|
-- Dagelijkse taak om a.d.h.v. het kenmerk leidinggevende bij de afdeling, de budgethouder
|
|
-- bij de kostenplaats te bepalen. Indien de afdeling geen leidinggevende heeft wordt in de
|
|
-- organisatieboom naar boven gezocht totdat er een leidinggevende gevonden is.
|
|
CREATE OR REPLACE PROCEDURE aaes_set_budgethouder
|
|
AS
|
|
BEGIN
|
|
|
|
DELETE aaes_leidinggevende_afd;
|
|
|
|
INSERT INTO aaes_leidinggevende_afd (prs_kostenplaats_key, prs_perslid_key)
|
|
(SELECT a.prs_kostenplaats_key, prs_perslid_key_leid
|
|
FROM aaes_v_leidinggevende_afd la, prs_afdeling a
|
|
WHERE la.prs_afdeling_key = a.prs_afdeling_key);
|
|
|
|
UPDATE prs_kostenplaats k
|
|
SET prs_perslid_key =
|
|
(SELECT DISTINCT prs_perslid_key
|
|
FROM aaes_leidinggevende_afd la
|
|
WHERE la.prs_kostenplaats_key = k.prs_kostenplaats_key)
|
|
WHERE prs_kostenplaats_key > 40
|
|
AND prs_kostenplaats_verwijder IS NULL;
|
|
|
|
-- voeg leidinggevenden toe aan de autorisatiegroep 'Essent leidinggevende'
|
|
INSERT INTO fac_gebruikersgroep (prs_perslid_key, fac_groep_key)
|
|
SELECT DISTINCT prs_perslid_key, 183 -- Essent leidinggevende
|
|
FROM prs_kostenplaats k
|
|
WHERE NOT EXISTS
|
|
(SELECT prs_perslid_key
|
|
FROM fac_gebruikersgroep gg
|
|
WHERE k.prs_perslid_key = gg.prs_perslid_key
|
|
AND fac_groep_key = 183)
|
|
AND prs_perslid_key IS NOT NULL;
|
|
|
|
-- verwijder personen als leidinggevende als ze geen budgethouder meer zijn
|
|
DELETE fac_gebruikersgroep gg
|
|
WHERE fac_groep_key = 183
|
|
AND NOT EXISTS (SELECT prs_perslid_key
|
|
FROM prs_kostenplaats k
|
|
WHERE k.prs_perslid_key = gg.prs_perslid_key);
|
|
|
|
-- set profiel van de leidinggevende bij medewerkers van Essent (authenticatie is gevuld met IAM id)
|
|
-- profiel wordt niet aangepast voor AAFM medewerkers
|
|
UPDATE prs_perslid p
|
|
SET fac_profiel_key = 41
|
|
WHERE EXISTS (SELECT prs_perslid_key
|
|
FROM prs_kostenplaats kp
|
|
WHERE kp.prs_perslid_key = p.prs_perslid_key)
|
|
AND COALESCE(fac_profiel_key, 1) = 1
|
|
AND prs_perslid_authenticatie IS NOT NULL
|
|
AND UPPER(prs_perslid_email) NOT LIKE '%AA-FM.COM';
|
|
|
|
-- set het profiel van alle oud-leidinggevenden en nieuwe personen naar default 500.
|
|
-- profiel wordt niet aangepast voor AAFM medewerkers
|
|
UPDATE prs_perslid p
|
|
SET fac_profiel_key = 1
|
|
WHERE NOT EXISTS (SELECT prs_perslid_key
|
|
FROM prs_kostenplaats kp
|
|
WHERE kp.prs_perslid_key = p.prs_perslid_key)
|
|
AND COALESCE(fac_profiel_key, 41) = 41
|
|
AND prs_perslid_authenticatie IS NOT NULL
|
|
AND UPPER(prs_perslid_email) NOT LIKE '%AA-FM.COM';
|
|
|
|
END aaes_set_budgethouder;
|
|
/
|
|
|
|
-- AAES#24099: Alleen bepaalde catalogi(?) en alleen FO-status Optie/Definitief
|
|
-- (dus niet Blokkade en Vervallen)!
|
|
/* Formatted on 30-1-2014 17:15:16 (QP5 v5.136.908.31019) */
|
|
CREATE OR REPLACE VIEW AAES_V_RAP_RES_INFOBORD
|
|
(
|
|
AKTIEF,
|
|
OFFSET,
|
|
DAG,
|
|
TIJD_VAN,
|
|
TIJD_TOT,
|
|
RUIMTE,
|
|
CATALOGUS,
|
|
AANVRAGER,
|
|
GASTHEER,
|
|
OMSCHRIJVING,
|
|
STATUS,
|
|
LOCATIE_CODE,
|
|
GEBOUW_CODE,
|
|
VERDIEPING_CODE,
|
|
LOCATIE_OMSCHRIJVING,
|
|
GEBOUW_OMSCHRIJVING,
|
|
VERDIEPING_OMSCHRIJVING,
|
|
ALG_LOCATIE_KEY,
|
|
ALG_GEBOUW_KEY,
|
|
ALG_VERDIEPING_KEY
|
|
)
|
|
AS
|
|
SELECT (CASE
|
|
WHEN rrr.res_rsv_ruimte_van > SYSDATE THEN 'expected'
|
|
WHEN rrr.res_rsv_ruimte_tot < SYSDATE THEN 'passed'
|
|
ELSE 'active'
|
|
END)
|
|
aktief,
|
|
TRUNC ( (SYSDATE - rrr.res_rsv_ruimte_van) * 24 * 60) offset,
|
|
TO_CHAR (rrr.res_rsv_ruimte_van, 'dd-mm-yyyy') dag,
|
|
TO_CHAR (rrr.res_rsv_ruimte_van, 'hh24:mi') tijd_van,
|
|
TO_CHAR (rrr.res_rsv_ruimte_tot, 'hh24:mi') tijd_tot,
|
|
rrg.res_ruimte_nr ruimte,
|
|
rd.ins_discipline_omschrijving catalogus,
|
|
aanvrager.prs_perslid_naam_full aanvrager,
|
|
gastheer.prs_perslid_naam_full gastheer,
|
|
rrr.res_rsv_ruimte_omschrijving omschrijving,
|
|
sf.res_status_fo_omschrijving status,
|
|
l.alg_locatie_code locatie_code,
|
|
g.alg_gebouw_code gebouw_code,
|
|
v.alg_verdieping_code verdieping_code,
|
|
l.alg_locatie_omschrijving locatie_omschrijving,
|
|
g.alg_gebouw_code||'-'||g.alg_gebouw_naam gebouw_omschrijving,
|
|
v.alg_verdieping_omschrijving verdieping_omschrijving,
|
|
l.alg_locatie_key,
|
|
g.alg_gebouw_key,
|
|
v.alg_verdieping_key
|
|
FROM res_v_aanwezigrsv_ruimte rrr,
|
|
res_ruimte_opstelling rro,
|
|
res_v_res_ruimte_gegevens rrg,
|
|
prs_v_perslid_fullnames aanvrager,
|
|
prs_v_perslid_fullnames gastheer,
|
|
alg_locatie l,
|
|
alg_gebouw g,
|
|
alg_verdieping v,
|
|
res_status_fo sf,
|
|
res_activiteit a,
|
|
res_discipline rd
|
|
WHERE rrr.res_status_fo_key IN (1, 2) -- Alleen Optie + Definitief!
|
|
AND rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
|
AND rro.res_ruimte_key = rrg.res_ruimte_key
|
|
AND rrr.res_rsv_ruimte_host_key = gastheer.prs_perslid_key
|
|
AND rrr.res_rsv_ruimte_contact_key = aanvrager.prs_perslid_key
|
|
AND TRUNC (rrr.res_rsv_ruimte_van) = TRUNC (SYSDATE)
|
|
AND rrg.alg_locatie_key = l.alg_locatie_key
|
|
AND rrg.alg_gebouw_key = g.alg_gebouw_key
|
|
AND rrg.alg_verdieping_key = v.alg_verdieping_key
|
|
AND rrr.res_status_fo_key = sf.res_status_fo_key
|
|
AND rrr.res_activiteit_key = a.res_activiteit_key
|
|
--AND a.res_srtactiviteit_key = -1
|
|
AND rrg.res_discipline_key = rd.ins_discipline_key
|
|
AND NOT EXISTS
|
|
(SELECT 1
|
|
FROM fac_usrdata
|
|
WHERE fac_usrtab_key = 601 -- NietOpInfobord
|
|
AND fac.safe_to_number (fac_usrdata_code) =
|
|
rrg.res_ruimte_key);
|
|
|
|
-- Ticket 57464 - Rapport voor dashboard - Alle ingevoerde facturen van de vaste en variabele contracten
|
|
CREATE OR REPLACE VIEW AAES_V_RAP_CNT_FACTUREN
|
|
(
|
|
UITVOERENDE,
|
|
OPDRACHTNR,
|
|
BEDRAG_EXCL_BTW,
|
|
OPMERKING,
|
|
LOCATIES,
|
|
CONTRACTTYPE,
|
|
FACTUUR_KEY
|
|
)
|
|
AS
|
|
SELECT b.prs_bedrijf_naam,
|
|
'C'
|
|
|| cnt_contract_nummer_intern
|
|
|| NVL2 (cnt_contract_versie, '.' || cnt_contract_versie, '')
|
|
Opdrachtnr,
|
|
f.fin_factuur_totaal
|
|
Bedrag_excl_btw,
|
|
f.fin_factuur_opmerking
|
|
Opmerking,
|
|
(SELECT LISTAGG (loc.locatienaam, ' & ')
|
|
WITHIN GROUP (ORDER BY loc.locatienaam)
|
|
FROM (SELECT cp.cnt_contract_key,
|
|
cp.cnt_alg_plaats_code,
|
|
DECODE (
|
|
cp.cnt_alg_plaats_code,
|
|
'L', (SELECT alg_locatie_omschrijving
|
|
FROM alg_locatie l
|
|
WHERE cp.cnt_alg_plaats_key =
|
|
l.alg_locatie_key),
|
|
'G', (SELECT alg_locatie_omschrijving
|
|
FROM alg_locatie l, alg_gebouw g
|
|
WHERE cp.cnt_alg_plaats_key =
|
|
g.alg_gebouw_key
|
|
AND g.alg_locatie_key =
|
|
l.alg_locatie_key),
|
|
'Onbekend')
|
|
locatienaam
|
|
FROM cnt_contract_plaats cp
|
|
WHERE cp.cnt_alg_plaats_code IN ('G', 'L')
|
|
AND cnt_contract_plaats_verwijder IS NULL
|
|
AND c.cnt_contract_key = cp.cnt_contract_key) loc)
|
|
Locaties,
|
|
CASE
|
|
WHEN SUBSTR (ks.prs_kostensoort_UPPER, 1, 2) = 'CF'
|
|
THEN
|
|
'Vast'
|
|
WHEN SUBSTR (ks.prs_kostensoort_UPPER, 1, 2) = 'CV'
|
|
THEN
|
|
'Variabel'
|
|
ELSE
|
|
'Onbekend'
|
|
END
|
|
Type_Contract,
|
|
f.fin_factuur_key
|
|
FROM fin_factuur f,
|
|
prs_kostensoort ks,
|
|
fin_factuur_statuses fs,
|
|
cnt_contract c,
|
|
prs_bedrijf b
|
|
WHERE f.prs_kostensoort_key = ks.prs_kostensoort_key
|
|
AND f.fin_factuur_statuses_key = fs.fin_factuur_statuses_key
|
|
AND f.fin_factuur_verwijder IS NULL
|
|
AND fs.fin_factuur_statuses_omschr = 'Ingevoerd'
|
|
AND f.cnt_contract_key = c.cnt_contract_key
|
|
AND c.cnt_prs_bedrijf_key = b.prs_bedrijf_key
|
|
ORDER BY b.prs_bedrijf_naam;
|
|
|
|
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
|
/
|
|
BEGIN fac.registercustversion('AAES', 13); END;
|
|
/
|
|
|
|
------ 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 |