370 lines
14 KiB
SQL
370 lines
14 KiB
SQL
-- Script containing customer specific db-configuration for SGGR.
|
||
-- (c) 2012 SG|facilitor bv
|
||
-- $Revision$
|
||
-- $Id$
|
||
--
|
||
-- Support: +31 53 4800700
|
||
|
||
SET DEFINE OFF
|
||
SET ECHO ON
|
||
spool xsggr.lst
|
||
|
||
/* Formatted on 23-11-2012 15:40:04 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW sggr_v_rap_cnt_periode_saas
|
||
(
|
||
ax_nr,
|
||
bedrijf,
|
||
omschrijving,
|
||
referentie,
|
||
ingangsdatum,
|
||
maandbedrag,
|
||
kwartaalbedrag,
|
||
kortingpct,
|
||
opmerking,
|
||
indexdatum
|
||
)
|
||
AS
|
||
SELECT b.prs_leverancier_nr ax_nr,
|
||
b.prs_bedrijf_naam bedrijf,
|
||
c.cnt_contract_omschrijving omschrijving,
|
||
COALESCE (c.cnt_contract_nummer, c.cnt_contract_omschrijving)
|
||
referentie,
|
||
c.cnt_contract_looptijd_van ingangsdatum,
|
||
SUM (kc1.cnt_kenmerkcontract_waarde) maandbedrag,
|
||
3 * SUM (kc1.cnt_kenmerkcontract_waarde) kwartaalbedrag,
|
||
TO_CHAR (c.cnt_contract_korting) kortingpct,
|
||
c.cnt_contract_document opmerking,
|
||
kc2.cnt_kenmerkcontract_waarde indexdatum
|
||
FROM cnt_v_aanwezigcontract c,
|
||
prs_bedrijf b,
|
||
cnt_kenmerkcontract kc1,
|
||
cnt_kenmerk ck1,
|
||
cnt_srtkenmerk cks1,
|
||
(SELECT kc2.cnt_contract_key, kc2.cnt_kenmerkcontract_waarde
|
||
FROM cnt_kenmerkcontract kc2, cnt_kenmerk k2
|
||
WHERE kc2.cnt_kenmerk_key = k2.cnt_kenmerk_key
|
||
AND k2.cnt_srtkenmerk_key = 301 -- indexdatum
|
||
AND kc2.cnt_kenmerkcontract_verwijder IS NULL) kc2
|
||
WHERE c.ins_discipline_key = 481 -- 481 saas; 482 lic; 501 care
|
||
AND c.cnt_contract_status = 0
|
||
AND c.cnt_prs_bedrijf_key = b.prs_bedrijf_key
|
||
AND c.cnt_contract_key = kc1.cnt_contract_key
|
||
AND kc1.cnt_kenmerk_key = ck1.cnt_kenmerk_key
|
||
AND ck1.cnt_kenmerk_verwijder IS NULL
|
||
AND ck1.cnt_srtkenmerk_key = cks1.cnt_srtkenmerk_key
|
||
AND ( cks1.cnt_srtkenmerk_omschrijving LIKE '%rijs%'
|
||
OR cks1.cnt_srtkenmerk_omschrijving LIKE '%Hosting%'
|
||
OR cks1.cnt_srtkenmerk_omschrijving LIKE '%Korting%')
|
||
AND c.cnt_contract_key = kc2.cnt_contract_key(+)
|
||
AND c.cnt_contract_looptijd_van < SYSDATE
|
||
AND c.cnt_contract_looptijd_tot > SYSDATE
|
||
GROUP BY b.prs_leverancier_nr,
|
||
b.prs_bedrijf_naam,
|
||
c.cnt_contract_looptijd_van,
|
||
c.cnt_contract_omschrijving,
|
||
c.cnt_contract_nummer,
|
||
c.cnt_contract_document,
|
||
c.cnt_contract_korting,
|
||
kc2.cnt_kenmerkcontract_waarde
|
||
ORDER BY 1, 4;
|
||
|
||
CREATE OR REPLACE VIEW PRS_V_SGF_AFDELING
|
||
(
|
||
prs_afdeling_key,
|
||
prs_afdeling_naam
|
||
)
|
||
AS
|
||
SELECT prs_afdeling_key, prs_afdeling_naam
|
||
FROM prs_v_aanwezigafdeling
|
||
WHERE prs_afdeling_parentkey = 27;
|
||
|
||
CREATE OR REPLACE VIEW PRS_V_BUDGETHOUDER
|
||
(
|
||
PRS_PERSLID_KEY,
|
||
PRS_PERSLID_NAAM
|
||
)
|
||
AS
|
||
SELECT prs_kostenplaats_key, prs_perslid_naam_full
|
||
FROM prs_kostenplaats k, prs_v_perslid_fullnames p
|
||
WHERE prs_kostenplaats_begin < SYSDATE
|
||
AND (prs_kostenplaats_eind < SYSDATE
|
||
OR prs_kostenplaats_eind IS NULL)
|
||
AND prs_kostenplaats_verwijder IS NULL
|
||
AND p.prs_perslid_key = k.prs_perslid_key;
|
||
|
||
-- SGGR#23236 - Inzetten FACILITOR voor administratieve processen SGF!
|
||
CREATE OR REPLACE PROCEDURE sggr_select_INDEXWERK (p_applname IN VARCHAR2,
|
||
p_applrun IN VARCHAR2)
|
||
AS
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW sggr_v_export_INDEXWERK (RESULT, result_order)
|
||
AS
|
||
SELECT '', 0
|
||
FROM DUAL
|
||
WHERE 1 = 0;
|
||
|
||
/* Formatted on 4-12-2012 19:12:24 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE PROCEDURE sggr_export_INDEXWERK (p_applname IN VARCHAR2,
|
||
p_applrun IN VARCHAR2)
|
||
AS
|
||
CURSOR ccnt
|
||
IS
|
||
SELECT '['
|
||
|| TO_CHAR (x.cnt_contract_nummer_intern)
|
||
|| '|'
|
||
|| x.cnt_contract_omschrijving
|
||
|| '] '
|
||
aanduiding,
|
||
x.cnt_contract_key,
|
||
x.cnt_contract_nummer_intern,
|
||
x.cnt_contract_versie,
|
||
x.cnt_contract_looptijd_tot einddatum,
|
||
li.index_datum laatste_indexdatum,
|
||
x.cnt_contract_kosten,
|
||
x.cnt_contract_termijnkosten,
|
||
DECODE (x.cnt_prs_bedrijf_key, 1062, 2.0, 2.4) indexpct -- Voor AAFM 2.0%
|
||
FROM (SELECT c.*
|
||
FROM cnt_v_aanwezigcontract c
|
||
WHERE c.ins_discipline_key IN (481, 482, 501) -- SaaS/Onderhoud/Care
|
||
AND c.cnt_contract_status = 0 -- NIET Gesloten!
|
||
AND NOT EXISTS -- Beschouw alleen laatste versie van contracten
|
||
(SELECT 1
|
||
FROM cnt_v_aanwezigcontract
|
||
WHERE cnt_contract_nummer_intern =
|
||
c.cnt_contract_nummer_intern
|
||
AND cnt_contract_versie >
|
||
COALESCE (
|
||
c.cnt_contract_versie,
|
||
'0'
|
||
))) x
|
||
LEFT JOIN
|
||
(SELECT cnt_contract_key,
|
||
fac.safe_to_date (cnt_kenmerkcontract_waarde,
|
||
'dd-mm-yyyy')
|
||
index_datum
|
||
FROM cnt_kenmerkcontract kc, cnt_kenmerk k
|
||
WHERE cnt_kenmerkcontract_verwijder IS NULL
|
||
AND kc.cnt_kenmerk_key = k.cnt_kenmerk_key
|
||
AND k.cnt_srtkenmerk_key = 301) li -- Laatste index-datum
|
||
ON x.cnt_contract_key = li.cnt_contract_key
|
||
WHERE COALESCE (li.index_datum, SYSDATE) <
|
||
TO_DATE ('01012014', 'ddmmyyyy')
|
||
ORDER BY 3;
|
||
|
||
v_errorhint VARCHAR2 (1000);
|
||
v_errormsg VARCHAR2 (1000);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_new_contract_key NUMBER;
|
||
|
||
PROCEDURE upsert_cntkenmerk (p_contract_key IN NUMBER,
|
||
p_srtkenmerk_key IN NUMBER,
|
||
p_waarde IN VARCHAR2)
|
||
AS
|
||
v_kenmerk_key NUMBER;
|
||
v_srtkenmerk_kenmerktype VARCHAR2 (10);
|
||
v_srtkenmerk_lengte NUMBER;
|
||
v_waarde VARCHAR2 (255);
|
||
v_kenmerkcontract_key NUMBER;
|
||
BEGIN
|
||
-- Bepaal kenmerk van meegegeven contract en soort; deze moet bestaan!
|
||
SELECT cnt_kenmerk_key,
|
||
cnt_srtkenmerk_kenmerktype,
|
||
COALESCE (cnt_srtkenmerk_lengte, 255)
|
||
INTO v_kenmerk_key, v_srtkenmerk_kenmerktype, v_srtkenmerk_lengte
|
||
FROM cnt_contract c, cnt_kenmerk k, cnt_srtkenmerk sk
|
||
WHERE c.cnt_contract_key = p_contract_key
|
||
AND c.ins_discipline_key = k.cnt_srtcontract_key
|
||
AND k.cnt_kenmerk_verwijder IS NULL
|
||
AND k.cnt_srtkenmerk_key = sk.cnt_srtkenmerk_key
|
||
AND sk.cnt_srtkenmerk_verwijder IS NULL
|
||
AND sk.cnt_srtkenmerk_key = p_srtkenmerk_key;
|
||
|
||
v_waarde := SUBSTR (p_waarde, 1, v_srtkenmerk_lengte);
|
||
|
||
BEGIN
|
||
-- Bepaal bestaan/aanwezigheid huidige kenmerkwaarde?
|
||
SELECT cnt_kenmerkcontract_key
|
||
INTO v_kenmerkcontract_key
|
||
FROM cnt_kenmerkcontract kc
|
||
WHERE kc.cnt_contract_key = p_contract_key
|
||
AND kc.cnt_kenmerk_key = v_kenmerk_key
|
||
AND kc.cnt_kenmerkcontract_verwijder IS NULL;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
IF p_waarde IS NULL
|
||
THEN
|
||
RETURN;
|
||
END IF;
|
||
|
||
INSERT INTO cnt_kenmerkcontract (
|
||
cnt_contract_key,
|
||
cnt_kenmerk_key,
|
||
cnt_kenmerkcontract_waarde
|
||
)
|
||
VALUES (p_contract_key, v_kenmerk_key, v_waarde);
|
||
|
||
RETURN;
|
||
END;
|
||
|
||
IF p_waarde IS NULL
|
||
THEN
|
||
--DELETE FROM cnt_kenmerkcontract
|
||
-- WHERE cnt_kenmerkcontract_key = v_kenmerkcontract_key;
|
||
UPDATE cnt_kenmerkcontract
|
||
SET cnt_kenmerkcontract_verwijder = SYSDATE
|
||
WHERE cnt_kenmerkcontract_key = v_kenmerkcontract_key;
|
||
ELSE
|
||
UPDATE cnt_kenmerkcontract
|
||
SET cnt_kenmerkcontract_waarde = v_waarde,
|
||
cnt_kenmerkcontract_wijzig = SYSDATE
|
||
WHERE cnt_kenmerkcontract_key = v_kenmerkcontract_key;
|
||
END IF;
|
||
END;
|
||
BEGIN
|
||
-- Splitsen en indexeren FACILITOR-contracten.
|
||
FOR rc IN ccnt
|
||
LOOP
|
||
BEGIN
|
||
v_errorhint := 'Fout bij splitsen contract.';
|
||
|
||
cnt.splitscontract (rc.cnt_contract_key,
|
||
TO_DATE ('01012014', 'ddmmyyyy'), -- Splitsdatum
|
||
NULL,
|
||
NULL);
|
||
|
||
COMMIT;
|
||
|
||
-- Na splitsen wordt de nieuwe versie ge<67>ndexeerd.
|
||
v_errorhint := 'Fout bij bepalen nieuwe versie.';
|
||
|
||
SELECT cnt_contract_key
|
||
INTO v_new_contract_key
|
||
FROM cnt_v_aanwezigcontract
|
||
WHERE cnt_contract_nummer_intern = rc.cnt_contract_nummer_intern
|
||
AND cnt_contract_versie >
|
||
COALESCE (rc.cnt_contract_versie, '0');
|
||
|
||
v_errorhint := 'Fout bij toevoegen laatste indexdatum.';
|
||
upsert_cntkenmerk (v_new_contract_key, 301, -- Laatste index-datum
|
||
'01-01-2014');
|
||
COMMIT;
|
||
|
||
v_errorhint := 'Fout bij toevoegen laatste indexpercentage.';
|
||
upsert_cntkenmerk (v_new_contract_key, 302, -- Laatste index-datum
|
||
rc.indexpct);
|
||
COMMIT;
|
||
|
||
FOR rkc
|
||
IN ( SELECT kc.cnt_kenmerkcontract_key,
|
||
kc.cnt_kenmerkcontract_waarde cur_waarde,
|
||
ROUND (
|
||
fac.safe_to_number (kc.cnt_kenmerkcontract_waarde)
|
||
* ( (100 + rc.indexpct) / 100),
|
||
2
|
||
)
|
||
new_waarde
|
||
FROM cnt_kenmerkcontract kc,
|
||
cnt_kenmerk k,
|
||
cnt_srtkenmerk sk
|
||
WHERE 1 = 1
|
||
AND kc.cnt_contract_key = v_new_contract_key
|
||
AND kc.cnt_kenmerkcontract_verwijder IS NULL
|
||
AND kc.cnt_kenmerk_key = k.cnt_kenmerk_key
|
||
AND k.cnt_kenmerk_verwijder IS NULL
|
||
AND k.cnt_srtkenmerk_key = sk.cnt_srtkenmerk_key
|
||
AND sk.cnt_srtkenmerk_verwijder IS NULL
|
||
AND sk.cnt_srtkenmerk_kenmerktype = 'N'
|
||
AND ( sk.cnt_srtkenmerk_key = 241 -- Hosting
|
||
OR sk.cnt_srtkenmerk_key = 221 -- Tarief Consultant
|
||
OR sk.cnt_srtkenmerk_key = 222 -- Tarief Specialist
|
||
OR sk.cnt_srtkenmerk_upper LIKE '%PRIJS%')
|
||
ORDER BY k.cnt_kenmerk_volgnummer)
|
||
LOOP
|
||
v_errorhint := 'Fout bij bijwerken prijsveld.';
|
||
|
||
UPDATE cnt_kenmerkcontract
|
||
SET cnt_kenmerkcontract_waarde =
|
||
TO_CHAR (rkc.new_waarde, '999999D99')
|
||
WHERE cnt_kenmerkcontract_key = rkc.cnt_kenmerkcontract_key;
|
||
END LOOP;
|
||
|
||
COMMIT;
|
||
|
||
v_errorhint := 'Fout bij bijwerken jaarbedrag.';
|
||
|
||
UPDATE cnt_contract
|
||
SET cnt_contract_kosten =
|
||
ROUND (
|
||
fac.safe_to_number (rc.cnt_contract_kosten)
|
||
* ( (100 + rc.indexpct) / 100),
|
||
2
|
||
)
|
||
WHERE cnt_contract_key = v_new_contract_key;
|
||
|
||
v_errorhint := 'Fout bij bijwerken termijnbedrag.';
|
||
|
||
UPDATE cnt_contract
|
||
SET cnt_contract_termijnkosten =
|
||
ROUND (
|
||
fac.safe_to_number (rc.cnt_contract_termijnkosten)
|
||
* ( (100 + rc.indexpct) / 100),
|
||
2
|
||
)
|
||
WHERE cnt_contract_key = v_new_contract_key;
|
||
|
||
v_errorhint := 'Fout bij bijwerken index-tracking (CNTUPD).';
|
||
|
||
fac.trackaction (
|
||
'CNTUPD',
|
||
v_new_contract_key,
|
||
NULL,
|
||
NULL,
|
||
'Contract ge<67>ndexeerd met ' || TO_CHAR (rc.indexpct) || '%'
|
||
);
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||
v_errormsg :=
|
||
' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.writelog (p_applname,
|
||
'W',
|
||
rc.aanduiding || v_errormsg,
|
||
v_errorhint);
|
||
COMMIT;
|
||
END;
|
||
END LOOP;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||
v_errormsg :=
|
||
'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.writelog (p_applname,
|
||
'E',
|
||
'Proces INDEXWERK afgebroken!',
|
||
v_errormsg);
|
||
COMMIT;
|
||
END;
|
||
/
|
||
|
||
BEGIN adm.systrackscript('$Workfile: sggr.sql $', '$Revision$', 0); END;
|
||
/
|
||
BEGIN fac.registercustversion('SGGR', 3); END;
|
||
/
|
||
COMMIT;
|
||
spool off
|