209 lines
8.4 KiB
MySQL
209 lines
8.4 KiB
MySQL
-- Script containing customer specific db-configuration for KING.
|
|
-- (c) 2011 SG|facilitor bv
|
|
-- $Revision$
|
|
-- $Id$
|
|
--
|
|
-- Support: +31 53 4800700
|
|
|
|
SET DEFINE OFF
|
|
SET ECHO ON
|
|
spool xking.lst
|
|
|
|
/* Formatted on 18-3-2013 16:50:50 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE VIEW king_v_rap_inkoop_vs_budget
|
|
(
|
|
FCLT_F_JAAR,
|
|
FCLT_F_AANVRAGER,
|
|
KOSTENPLAATS,
|
|
JAARBUDGET,
|
|
INKOOP,
|
|
PERCENTAGE,
|
|
FCLT_3D_AFDELING_KEY
|
|
)
|
|
AS
|
|
SELECT COALESCE (y1.jaar, x.jaar),
|
|
x.aanvrager,
|
|
x.kostenplaats,
|
|
COALESCE (y3.jaarbudget, 0),
|
|
y1.inkoop,
|
|
DECODE (
|
|
y3.jaarbudget,
|
|
NULL,
|
|
TO_NUMBER (NULL),
|
|
0,
|
|
TO_NUMBER (NULL),
|
|
ROUND (
|
|
(COALESCE (y1.inkoop, 0)
|
|
/ DECODE (y3.jaarbudget, NULL, 1, 0, 1, y3.jaarbudget))
|
|
* 100,
|
|
2
|
|
) --,
|
|
),
|
|
x.prs_afdeling_key
|
|
FROM (SELECT p.prs_perslid_key,
|
|
p.prs_afdeling_key,
|
|
pf.prs_perslid_naam_full aanvrager,
|
|
k.prs_kostenplaats_nr kostenplaats,
|
|
periode.jaar
|
|
FROM prs_perslid p,
|
|
prs_v_perslid_fullnames_all pf,
|
|
prs_v_afdeling a,
|
|
prs_kostenplaats k,
|
|
( SELECT TO_CHAR (2011 + ROWNUM - 1) jaar
|
|
FROM DUAL
|
|
CONNECT BY LEVEL <=
|
|
(TO_NUMBER (
|
|
TO_CHAR (SYSDATE, 'yyyy')
|
|
)
|
|
- 2011
|
|
+ 1)) periode
|
|
WHERE UPPER (p.prs_perslid_voornaam) LIKE '%BUDGET%'
|
|
AND p.prs_perslid_key = pf.prs_perslid_key
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND a.prs_kostenplaats_key =
|
|
k.prs_kostenplaats_key(+)) x
|
|
LEFT JOIN
|
|
( SELECT p.prs_perslid_key,
|
|
TO_CHAR (b.bes_bestelling_datum, 'yyyy') jaar,
|
|
ROUND (
|
|
SUM(bi.bes_bestelling_item_aantal
|
|
* bi.bes_bestelling_item_prijs),
|
|
2
|
|
)
|
|
inkoop
|
|
FROM bes_bestelling b,
|
|
bes_bestelling_item bi,
|
|
prs_perslid p
|
|
WHERE b.bes_bestelling_key = bi.bes_bestelling_key
|
|
AND b.prs_perslid_key = p.prs_perslid_key
|
|
AND UPPER (p.prs_perslid_voornaam) LIKE
|
|
'%BUDGET%'
|
|
AND b.bes_bestelling_status <> 1
|
|
GROUP BY p.prs_perslid_key,
|
|
TO_CHAR (b.bes_bestelling_datum, 'yyyy')) y1
|
|
ON x.prs_perslid_key = y1.prs_perslid_key AND x.jaar = y1.jaar
|
|
--LEFT JOIN
|
|
-- (SELECT p.prs_perslid_key,
|
|
-- pgb.fac_profiel_limiet jaarbudget
|
|
-- FROM prs_perslid p, fac_profiel pgb
|
|
-- WHERE p.fac_profiel_key = pgb.fac_profiel_key) y2
|
|
--ON x.prs_perslid_key = y2.prs_perslid_key
|
|
LEFT JOIN
|
|
(SELECT kl.prs_link_key,
|
|
fac.safe_to_number (kl.prs_kenmerklink_waarde)
|
|
jaarbudget
|
|
FROM prs_v_aanwezigkenmerklink kl
|
|
WHERE kl.prs_kenmerk_key = 1000 -- Jaarbudget?
|
|
AND kl.prs_kenmerklink_niveau = 'P') y3
|
|
ON x.prs_perslid_key = y3.prs_link_key;
|
|
|
|
/* Formatted on 18-10-2011 12:56:56 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE VIEW king_v_rap_inkoop_tbv_regie
|
|
(
|
|
FCLT_F_MAAND,
|
|
FCLT_F_AANVRAGER,
|
|
KOSTENPLAATS,
|
|
BESTELNR,
|
|
BESTELD_OP,
|
|
ARTIKEL_NR,
|
|
ARTIKEL,
|
|
AANTAL,
|
|
PRIJS,
|
|
PRIJS_TOT,
|
|
FCLT_3D_AFDELING_KEY
|
|
)
|
|
AS
|
|
SELECT NVL2 (y.bes_bestelling_datum,
|
|
TO_CHAR (y.bes_bestelling_datum, 'yyyy-mm'),
|
|
TO_CHAR (SYSDATE, 'yyyy-mm')),
|
|
x.aanvrager,
|
|
x.kostenplaats,
|
|
TO_CHAR (y.bes_bestelling_key) bestelnummer,
|
|
TO_CHAR (y.bes_bestelling_datum, 'dd-mm-yyyy') besteld_op,
|
|
y.bes_srtdeel_nr artikelnummer,
|
|
y.bes_srtdeel_omschrijving artikelomschrijving,
|
|
TO_CHAR (y.bes_bestelling_item_aantal) aantal,
|
|
REPLACE (TO_CHAR (y.bes_bestelling_item_prijs), '.', ',') prijs,
|
|
(y.bes_bestelling_item_aantal * y.bes_bestelling_item_prijs)
|
|
prijs_tot,
|
|
x.prs_afdeling_key
|
|
FROM (SELECT p.prs_perslid_key,
|
|
p.prs_afdeling_key,
|
|
pf.prs_perslid_naam_full aanvrager,
|
|
k.prs_kostenplaats_nr kostenplaats
|
|
FROM prs_perslid p,
|
|
prs_v_perslid_fullnames_all pf,
|
|
prs_v_afdeling a,
|
|
prs_kostenplaats k
|
|
WHERE UPPER (p.prs_perslid_voornaam) LIKE '%REGIE%'
|
|
AND p.prs_perslid_key = pf.prs_perslid_key
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND a.prs_kostenplaats_key =
|
|
k.prs_kostenplaats_key(+)) x
|
|
LEFT JOIN
|
|
(SELECT b.prs_perslid_key,
|
|
b.bes_bestelling_key,
|
|
b.bes_bestelling_datum,
|
|
sd.bes_srtdeel_nr,
|
|
sd.bes_srtdeel_omschrijving,
|
|
bi.bes_bestelling_item_aantal,
|
|
bi.bes_bestelling_item_prijs
|
|
FROM bes_bestelling b,
|
|
bes_bestelling_item bi,
|
|
bes_srtdeel sd
|
|
WHERE b.bes_bestelling_key = bi.bes_bestelling_key
|
|
AND bi.bes_srtdeel_key = sd.bes_srtdeel_key
|
|
AND b.bes_bestelling_status <> 1) y
|
|
ON x.prs_perslid_key = y.prs_perslid_key;
|
|
|
|
-- Bevat een kopie van alle in voorgaande uur aangemaakt BES-notificaties naar
|
|
-- pseudo-bestellers, die de rayon-besteller (als FO-user) ook wil zien!
|
|
/* Formatted on 7-11-2011 11:10:30 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE VIEW KING_V_NOTI_RAYON_BESTELLERS
|
|
(
|
|
code,
|
|
sender,
|
|
receiver,
|
|
text,
|
|
KEY,
|
|
par1,
|
|
par2,
|
|
xkey
|
|
)
|
|
AS
|
|
SELECT sn.fac_srtnotificatie_code,
|
|
NULL,
|
|
rb.prs_perslid_key,
|
|
REPLACE (sn.fac_srtnotificatie_oms,
|
|
'##KEY##',
|
|
t.fac_tracking_refkey),
|
|
t.fac_tracking_refkey,
|
|
NULL,
|
|
NULL,
|
|
NULL
|
|
FROM fac_tracking t,
|
|
fac_srtnotificatie sn,
|
|
bes_bestelling b,
|
|
prs_v_aanwezigperslid pb, -- pseudo-besteller
|
|
prs_v_afdeling_boom ab,
|
|
prs_v_aanwezigperslid rb -- rayon-besteller
|
|
WHERE t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_code LIKE 'BES%'
|
|
AND sn.fac_srtnotificatie_code NOT LIKE 'BES2%'
|
|
AND sn.fac_srtnotificatie_code <> 'BESAP1'
|
|
AND t.fac_tracking_refkey = b.bes_bestelling_key
|
|
AND b.prs_perslid_key = pb.prs_perslid_key
|
|
AND pb.prs_afdeling_key = ab.prs_afdeling_key
|
|
AND ab.prs_afdeling_key1 = rb.prs_afdeling_key
|
|
AND TRUNC (t.fac_tracking_datum) = TRUNC (SYSDATE)
|
|
AND TO_NUMBER (TO_CHAR (t.fac_tracking_datum, 'HH24')) + 1 =
|
|
TO_NUMBER (TO_CHAR (SYSDATE, 'HH24'))
|
|
ORDER BY t.fac_tracking_datum;
|
|
|
|
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
|
/
|
|
BEGIN fac.registercustversion('KING', 5); END;
|
|
/
|
|
COMMIT;
|
|
spool off
|