svn path=/Customer/trunk/; revision=15243
This commit is contained in:
337
CSUN/CSUN.sql
337
CSUN/CSUN.sql
@@ -1,7 +1,7 @@
|
||||
-- Script containing customer specific configuration sql statements for CSUN: CSU National Accounts
|
||||
-- (c) 2011 SG|facilitor
|
||||
-- $Revision: 3 $
|
||||
-- $Modtime: 9-03-12 14:48 $
|
||||
-- $Revision: 4 $
|
||||
-- $Modtime: 6-04-12 11:04 $
|
||||
--
|
||||
-- Support: +31 53 4800710
|
||||
|
||||
@@ -540,6 +540,82 @@ AS
|
||||
AND m.mld_melding_key = tr.fac_tracking_refkey(+)
|
||||
AND m.mld_melding_status = st.mld_statuses_key;
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW CSUN_V_RAP_MELDING_SANQ
|
||||
(
|
||||
MELDING,
|
||||
RL,
|
||||
DM,
|
||||
LOCATIE,
|
||||
RC,
|
||||
RC_TELEFOON,
|
||||
RC_MAIL,
|
||||
DATUM_MELDING,
|
||||
TIJDSTIP_MELDING,
|
||||
MAAND_MELDING,
|
||||
MELDER,
|
||||
AARD_MELDING,
|
||||
OMSCHRIJVING,
|
||||
RUIMTE_CATEGORIE,
|
||||
RUIMTE_NUMMER,
|
||||
URGENTIEKLASSE,
|
||||
ONDERNOMEN_ACTIES,
|
||||
RESULTAAT,
|
||||
PREVENTIE,
|
||||
STATUS,
|
||||
DATUM_AFGEHANDELD,
|
||||
TIJDSTIP_AFGEHANDELD,
|
||||
AFHANDELTIJD_UREN,
|
||||
AFHANDELTIJD_DAGEN,
|
||||
BIJZONDERHEDEN
|
||||
)
|
||||
AS
|
||||
SELECT mld_melding_key,
|
||||
NULL rl,
|
||||
NULL dm,
|
||||
alg_locatie_omschrijving,
|
||||
NULL rc_sanquin,
|
||||
NULL telefoonnummer,
|
||||
NULL mailadres,
|
||||
TO_CHAR (mld_melding_datum, 'dd-mm-yyyy') datum,
|
||||
TO_CHAR (mld_melding_datum, 'hh24:mi') tijdstip,
|
||||
fac.safe_to_number (TO_CHAR (mld_melding_datum, 'mm')) maand,
|
||||
pf.prs_perslid_naam_full melder,
|
||||
std.mld_stdmelding_omschrijving aard,
|
||||
mld_melding_omschrijving omschrijving,
|
||||
NULL ruimte_categorie,
|
||||
NULL ruimte_nummer,
|
||||
mld_melding_spoed urgentieklasse,
|
||||
-- decode (mld_melding_spoed, null vereistehersteltijd,
|
||||
mld_melding_opmerking ondernomenacties,
|
||||
NULL resultaat,
|
||||
NULL preventie,
|
||||
mld_statuses_omschrijving status,
|
||||
TO_CHAR (einddatum.datum, 'dd-mm-yyyy') datumafgehandeld,
|
||||
TO_CHAR (einddatum.datum, 'hh24:mi') tijdstipafgehandeld,
|
||||
csu_count_WorkHours (mld_melding_datum, einddatum.datum)
|
||||
afgehandelduren,
|
||||
ROUND (
|
||||
csu_count_WorkHours (mld_melding_datum, einddatum.datum) / 9,
|
||||
2)
|
||||
afgehandelddagen,
|
||||
NULL bijzonderheden
|
||||
FROM mld_melding m,
|
||||
alg_locatie l,
|
||||
prs_v_perslid_fullnames_all pf,
|
||||
mld_stdmelding std,
|
||||
mld_statuses st,
|
||||
(SELECT fac_tracking_refkey, fac_tracking_datum datum
|
||||
FROM fac_tracking
|
||||
WHERE fac_srtnotificatie_key = 35) einddatum
|
||||
WHERE m.mld_alg_locatie_key = l.alg_locatie_key
|
||||
AND m.prs_perslid_key = pf.prs_perslid_key
|
||||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||||
AND m.mld_melding_key = einddatum.fac_tracking_refkey(+)
|
||||
AND m.mld_melding_status = st.mld_statuses_key;
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE FORCE VIEW CSUN_V_RAP_DISTRICTGEGEVENS
|
||||
(
|
||||
FCLT_F_BUSINESSUNIT,
|
||||
@@ -1409,6 +1485,263 @@ END csun_update_onrgoed;
|
||||
/
|
||||
|
||||
|
||||
--
|
||||
-- Procedures en functies om de doorlooptijd van meldingen te bepalen
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION csu_find_next_workingday (pdate1 IN DATE)
|
||||
RETURN DATE
|
||||
IS
|
||||
result DATE;
|
||||
v_vrije_dagen NUMBER;
|
||||
v_date DATE;
|
||||
BEGIN
|
||||
v_date := pdate1;
|
||||
|
||||
IF pdate1 < (TRUNC (v_date) + 8 / 24)
|
||||
THEN
|
||||
v_date := TRUNC (v_date) + 8 / 24;
|
||||
END IF;
|
||||
|
||||
IF pdate1 > (TRUNC (v_date) + 17 / 24)
|
||||
THEN
|
||||
v_date := TRUNC (v_date) + 17 / 24;
|
||||
END IF;
|
||||
|
||||
IF TO_CHAR (v_date, 'd') IN (1, 7)
|
||||
THEN
|
||||
result := csu_find_next_workingday (TRUNC (v_date) + 1 + 8 / 24);
|
||||
ELSE
|
||||
SELECT COUNT ( * )
|
||||
INTO v_vrije_dagen
|
||||
FROM mld_vrije_dagen
|
||||
WHERE mld_vrije_dagen_datum = TRUNC (v_date);
|
||||
|
||||
IF v_vrije_dagen = 1
|
||||
THEN
|
||||
result := csu_find_next_workingday (TRUNC (v_date) + 1 + 8 / 24);
|
||||
ELSE
|
||||
result := v_date;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN result;
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION csu_find_prev_workingday (pdate1 IN DATE)
|
||||
RETURN DATE
|
||||
IS
|
||||
result DATE;
|
||||
v_vrije_dagen NUMBER;
|
||||
v_date DATE;
|
||||
BEGIN
|
||||
v_date := pdate1;
|
||||
|
||||
IF pdate1 < (TRUNC (v_date) + 8 / 24)
|
||||
THEN
|
||||
v_date := TRUNC (v_date) + 8 / 24;
|
||||
END IF;
|
||||
|
||||
IF pdate1 > (TRUNC (v_date) + 17 / 24)
|
||||
THEN
|
||||
v_date := TRUNC (v_date) + 17 / 24;
|
||||
END IF;
|
||||
|
||||
IF TO_CHAR (v_date, 'd') IN (1, 7)
|
||||
THEN
|
||||
result := csu_find_prev_workingday (TRUNC (v_date) - 1 + 17 / 24);
|
||||
ELSE
|
||||
SELECT COUNT ( * )
|
||||
INTO v_vrije_dagen
|
||||
FROM mld_vrije_dagen
|
||||
WHERE mld_vrije_dagen_datum = TRUNC (v_date);
|
||||
|
||||
IF v_vrije_dagen = 1
|
||||
THEN
|
||||
result := csu_find_prev_workingday (TRUNC (v_date) - 1 + 17 / 24);
|
||||
ELSE
|
||||
result := v_date;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN result;
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE FUNCTION csu_count_WorkHours (pdate_from IN DATE,
|
||||
pdate_to IN DATE)
|
||||
RETURN NUMBER
|
||||
IS
|
||||
eikdag NUMBER;
|
||||
v_date_from DATE;
|
||||
v_date_to DATE;
|
||||
v_week NUMBER;
|
||||
v_mod NUMBER;
|
||||
v_holidays NUMBER;
|
||||
v_beginuur NUMBER (5, 2);
|
||||
v_einduur NUMBER (5, 2);
|
||||
v_correction NUMBER;
|
||||
BEGIN
|
||||
-- Dit is een maandag, is dat volgens de huidige territory dag 2?
|
||||
SELECT TO_NUMBER (TO_CHAR (TO_DATE ('01-01-2007', 'DD-MM-YYYY'), 'D'))
|
||||
INTO eikdag
|
||||
FROM DUAL;
|
||||
|
||||
IF eikdag <> 2
|
||||
THEN
|
||||
-- WE MOETEN met zondag=1 werken (geen nieuwe eis, wel duidelijker probleem)
|
||||
raise_application_error (-20000, 'Facilitor: Invalid NLS_TERRITORY');
|
||||
END IF;
|
||||
|
||||
v_date_from := csu_find_prev_workingday (pdate_from);
|
||||
v_date_to := csu_find_next_workingday (pdate_to);
|
||||
|
||||
DBMS_OUTPUT.put_line (
|
||||
'v_date_from:' || v_date_from || ' v_date_to:' || v_date_to);
|
||||
|
||||
-- Determine whole weeks (v_week) and remaining days (v_mod) between FROM and TO
|
||||
v_week := TRUNC ( (TRUNC (v_date_to) - TRUNC (v_date_from)) / 7);
|
||||
v_mod := MOD ( (TRUNC (v_date_to) - TRUNC (v_date_from)), 7);
|
||||
|
||||
-- Determine the registered holidays between FROM and TO
|
||||
SELECT COUNT ( * )
|
||||
INTO v_holidays
|
||||
FROM MLD_VRIJE_DAGEN
|
||||
WHERE MLD_VRIJE_DAGEN_DATUM BETWEEN v_date_from AND v_date_to;
|
||||
|
||||
v_beginuur := (TRUNC (v_date_from, 'MI') - TRUNC (v_date_from)) * 24;
|
||||
v_einduur := (TRUNC (v_date_to, 'MI') - TRUNC (v_date_to)) * 24;
|
||||
|
||||
DBMS_OUTPUT.put_line (
|
||||
'v_beginuur:' || v_beginuur || ' v_einduur:' || v_einduur);
|
||||
|
||||
IF v_einduur - v_beginuur > 0
|
||||
THEN
|
||||
v_correction := v_einduur - v_beginuur;
|
||||
ELSE
|
||||
v_correction := v_einduur - v_beginuur;
|
||||
END IF;
|
||||
|
||||
DBMS_OUTPUT.put_line( 'v_week:'
|
||||
|| v_week
|
||||
|| ' v_mod:'
|
||||
|| v_mod
|
||||
|| ' v_holidays:'
|
||||
|| v_holidays
|
||||
|| ' v_correction: '
|
||||
|| v_correction);
|
||||
RETURN 9 * ( (5 * v_week) + v_mod - v_holidays) + v_correction;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
RETURN NULL;
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
CREATE OR REPLACE PROCEDURE csun_export_set_werkplek (
|
||||
p_applname IN VARCHAR2,
|
||||
p_applrun IN VARCHAR2,
|
||||
p_filedir IN VARCHAR2,
|
||||
p_filename IN VARCHAR2
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
-- toevoegen gebouwen
|
||||
INSERT INTO alg_gebouw (alg_locatie_key,
|
||||
alg_srtgebouw_key,
|
||||
alg_gebouw_naam,
|
||||
alg_gebouw_code)
|
||||
SELECT alg_locatie_key,
|
||||
40,
|
||||
'Onbekend',
|
||||
'O'
|
||||
FROM alg_locatie l
|
||||
WHERE NOT EXISTS (SELECT alg_locatie_key
|
||||
FROM alg_gebouw g
|
||||
WHERE g.alg_locatie_key = l.alg_locatie_key)
|
||||
AND alg_locatie_omschrijving NOT LIKE 'CSU%';
|
||||
|
||||
-- toevoegen verdiepingen
|
||||
INSERT INTO alg_verdieping (alg_gebouw_key,
|
||||
alg_verdieping_omschrijving,
|
||||
alg_verdieping_volgnr,
|
||||
alg_verdieping_code)
|
||||
SELECT alg_gebouw_key,
|
||||
'Onbekend',
|
||||
1,
|
||||
'O'
|
||||
FROM alg_gebouw g
|
||||
WHERE NOT EXISTS (SELECT alg_gebouw_key
|
||||
FROM alg_verdieping v
|
||||
WHERE v.alg_gebouw_key = g.alg_gebouw_key);
|
||||
|
||||
-- toevoegen ruimten
|
||||
INSERT INTO alg_ruimte (alg_verdieping_key,
|
||||
alg_ruimte_nr,
|
||||
alg_srtruimte_key,
|
||||
alg_ruimte_omschrijving)
|
||||
SELECT alg_verdieping_key,
|
||||
'-',
|
||||
1,
|
||||
'Onbekend'
|
||||
FROM alg_v_aanwezigverdieping v
|
||||
WHERE NOT EXISTS (SELECT alg_verdieping_key
|
||||
FROM alg_ruimte r
|
||||
WHERE r.alg_verdieping_key = v.alg_verdieping_key);
|
||||
|
||||
-- toevoegen werkplekken
|
||||
INSERT INTO prs_werkplek (prs_werkplek_volgnr, prs_werkplek_virtueel, prs_alg_ruimte_key)
|
||||
SELECT 1, 0, alg_ruimte_key
|
||||
FROM alg_v_aanwezigruimte r
|
||||
WHERE NOT EXISTS
|
||||
(SELECT wp.prs_alg_ruimte_key
|
||||
FROM prs_v_aanwezigwerkplek wp
|
||||
WHERE r.alg_ruimte_key = wp.prs_alg_ruimte_key
|
||||
AND prs_werkplek_volgnr = 1);
|
||||
|
||||
-- toevoegen prs_perslidwerkplekken
|
||||
INSERT INTO prs_perslidwerkplek (prs_perslid_key, prs_perslidwerkplek_bezetting, prs_werkplek_key)
|
||||
SELECT prs_perslid_key, 100, prs_werkplek_key
|
||||
FROM prs_v_aanwezigperslid p,
|
||||
prs_afdeling a,
|
||||
alg_onrgoedkenmerk aogk,
|
||||
fac_usrdata ud,
|
||||
prs_v_werkplek_gegevens wpg
|
||||
WHERE p.prs_afdeling_key = a.prs_afdeling_key
|
||||
AND a.prs_afdeling_verwijder IS NULL
|
||||
AND a.prs_afdeling_naam IN
|
||||
('Adecco',
|
||||
'Manpower',
|
||||
'Luba',
|
||||
'Servex',
|
||||
'USG PA',
|
||||
'USG People')
|
||||
AND fac.safe_to_number (aogk.alg_onrgoedkenmerk_waarde) =
|
||||
fac_usrdata_key
|
||||
AND aogk.alg_kenmerk_key = 1000
|
||||
AND aogk.alg_onrgoed_key = wpg.alg_locatie_key
|
||||
AND wpg.prs_werkplek_volgnr = 1
|
||||
AND UPPER (prs_afdeling_naam) LIKE UPPER (fac_usrdata_code) || '%'
|
||||
AND fac_usrtab_key = 1
|
||||
AND EXISTS
|
||||
(SELECT gg.prs_perslid_key
|
||||
FROM fac_gebruikersgroep gg
|
||||
WHERE fac_groep_key = 61
|
||||
AND gg.prs_perslid_key = p.prs_perslid_key)
|
||||
AND NOT EXISTS
|
||||
(SELECT prs_perslidwerkplek_key
|
||||
FROM prs_perslidwerkplek pwp
|
||||
WHERE pwp.prs_perslid_key = p.prs_perslid_key
|
||||
AND wpg.prs_werkplek_key = pwp.prs_werkplek_key);
|
||||
|
||||
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
BEGIN fac.registercustversion('CSUN', 3); END;
|
||||
/
|
||||
|
||||
127
PNBR/pnbr.sql
127
PNBR/pnbr.sql
@@ -1,7 +1,7 @@
|
||||
-- Script containing customer generic configuration sql statements for PNBR
|
||||
-- (c) 2011 SG|facilitor
|
||||
-- $Revision: 1 $
|
||||
-- $Modtime: 8-03-12 16:09 $
|
||||
-- $Revision: 2 $
|
||||
-- $Modtime: 9-04-12 22:18 $
|
||||
--
|
||||
-- Support: +31 53 4800710
|
||||
|
||||
@@ -131,10 +131,7 @@ BEGIN
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE pnbr_import_organisatie_mut (p_import_key IN NUMBER,
|
||||
p_filedir IN VARCHAR2,
|
||||
p_filename IN VARCHAR2
|
||||
)
|
||||
CREATE OR REPLACE PROCEDURE pnbr_import_organisatie_mut (p_import_key IN NUMBER)
|
||||
AS
|
||||
c_fielddelimitor VARCHAR2 (1) := ';';
|
||||
v_newline VARCHAR2 (1000); -- Input line
|
||||
@@ -256,6 +253,7 @@ BEGIN
|
||||
);
|
||||
END IF;
|
||||
|
||||
v_kostenplaats := LTRIM(v_kostenplaats, '0');
|
||||
v_all_null :=
|
||||
(v_bedrijf_naam IS NULL)
|
||||
AND (v_afdeling_naam IS NULL)
|
||||
@@ -348,7 +346,7 @@ BEGIN
|
||||
fac.imp_writelog (p_import_key,
|
||||
'I',
|
||||
'Facilitor afdeling import version ' || currentversion,
|
||||
'$Revision: 1 $'
|
||||
'$Revision: 2 $'
|
||||
);
|
||||
|
||||
-- How many active records are now present?
|
||||
@@ -513,7 +511,10 @@ BEGIN
|
||||
|
||||
UPDATE prs_kostenplaats k
|
||||
SET prs_kostenplaats_verwijder = SYSDATE
|
||||
WHERE NOT EXISTS (SELECT prs
|
||||
WHERE NOT EXISTS (SELECT i.prs_kostenplaats_nr
|
||||
FROM fac_imp_organisatie i
|
||||
WHERE i.prs_kostenplaats_nr = k.prs_kostenplaats_nr)
|
||||
AND prs_kostenplaats_verwijder IS NULL;
|
||||
|
||||
UPDATE prs_afdeling a
|
||||
SET prs_afdeling_omschrijving =
|
||||
@@ -572,6 +573,27 @@ AS
|
||||
FROM fac_import
|
||||
GROUP BY fac_import_app_key);
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_v_rap_notificatie
|
||||
(
|
||||
fclt_f_module,
|
||||
code,
|
||||
omschrijving,
|
||||
fclt_f_status,
|
||||
fclt_f_mail,
|
||||
fclt_f_sms,
|
||||
fclt_f_alert
|
||||
)
|
||||
AS
|
||||
SELECT SUBSTR (fac_srtnotificatie_code, 1, 3) module,
|
||||
fac_srtnotificatie_code,
|
||||
fac_srtnotificatie_oms,
|
||||
DECODE (BITAND (fac_srtnotificatie_mode, 1), 0, '', 'status')
|
||||
status,
|
||||
DECODE (BITAND (fac_srtnotificatie_mode, 2), 0, '', 'mail') mail,
|
||||
DECODE (BITAND (fac_srtnotificatie_mode, 4), 0, '', 'sms') sms,
|
||||
DECODE (BITAND (fac_srtnotificatie_mode, 8), 0, '', 'alert') alert
|
||||
FROM fac_srtnotificatie;
|
||||
|
||||
CREATE OR REPLACE FORCE VIEW PNBR_V_RAP_VOORRAAD
|
||||
(
|
||||
HIDE_F_EXTERN_DISKEY,
|
||||
@@ -580,13 +602,14 @@ CREATE OR REPLACE FORCE VIEW PNBR_V_RAP_VOORRAAD
|
||||
ARTIKEL_NR,
|
||||
ARTIKEL_OMSCHRIJVING,
|
||||
ARTIKEL_PRIJS,
|
||||
MAGAZIJN,
|
||||
MIN_VOORRAAD,
|
||||
MAX_VOORRAAD,
|
||||
INKOOP_GELEVERD,
|
||||
INTERN_BESTELD,
|
||||
VOORRAAD,
|
||||
HIDE_F_VOORRAAD_GISTEREN,
|
||||
INKOOP_BESTELD,
|
||||
INKOOP_LEVERDATUM,
|
||||
INKOOP_GEWENST
|
||||
)
|
||||
AS
|
||||
@@ -599,14 +622,14 @@ AS
|
||||
COALESCE (intern.bes_srtdeel_omschrijving,
|
||||
extern.bes_srtdeel_omschrijving),
|
||||
COALESCE (intern.srtdeel_prijs, extern.srtdeel_prijs),
|
||||
intern.magazijn,
|
||||
extern.vmin,
|
||||
extern.vmax,
|
||||
extern.geleverd,
|
||||
intern.besteld,
|
||||
extern.geleverd - COALESCE (intern.besteld, 0) voorraad,
|
||||
extern.geleverd_gisteren - COALESCE (intern.besteld_gisteren, 0)
|
||||
voorraad_gisteren,
|
||||
extern.besteld,
|
||||
TO_CHAR(extern.leverdatum, 'dd-mm-yyyy'),
|
||||
CASE
|
||||
WHEN ( (COALESCE (extern.besteld, 0)
|
||||
+ COALESCE (extern.geleverd, 0))
|
||||
@@ -629,25 +652,28 @@ AS
|
||||
bd.ins_discipline_omschrijving, -- ext. catalogusnaam
|
||||
sd.bes_srtdeel_voorraadmin vmin, -- ext. voorraadmin
|
||||
sd.bes_srtdeel_voorraadmax vmax, -- ext. voorraadmax
|
||||
(SELECT SUM (bi.bes_bestelling_item_aantal)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi
|
||||
WHERE b.bes_bestelling_status IN (2, 3, 4, 5)
|
||||
(SELECT SUM (coalesce(boi.bes_bestelopdr_item_aantal, bi.bes_bestelling_item_aantal)-COALESCE(boi.bes_bestelopdr_item_aantalontv,0))
|
||||
FROM bes_bestelling b, bes_bestelling_item bi, bes_bestelopdr_item boi
|
||||
WHERE boi.bes_bestelopdr_item_key(+) = bi.bes_bestelopdr_item_key
|
||||
AND bi.bes_bestelling_item_status IN (2, 3, 4, 5)
|
||||
AND b.bes_bestelling_key = bi.bes_bestelling_key
|
||||
AND bi.bes_srtdeel_key = sd.bes_srtdeel_key)
|
||||
besteld,
|
||||
(SELECT SUM (bi.bes_bestelling_item_aantal)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi
|
||||
WHERE b.bes_bestelling_status > 5
|
||||
(SELECT MIN (b.bes_bestelling_leverdatum)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi, bes_bestelopdr_item boi
|
||||
WHERE boi.bes_bestelopdr_item_key(+) = bi.bes_bestelopdr_item_key
|
||||
AND bi.bes_bestelling_item_status IN (2, 3, 4, 5)
|
||||
AND COALESCE(bes_bestelopdr_item_aantal, bi.bes_bestelling_item_aantal) <> COALESCE(bes_bestelopdr_item_aantalontv, 0)
|
||||
AND b.bes_bestelling_key = bi.bes_bestelling_key
|
||||
AND bi.bes_srtdeel_key = sd.bes_srtdeel_key)
|
||||
geleverd,
|
||||
(SELECT SUM (bi.bes_bestelling_item_aantal)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi
|
||||
WHERE b.bes_bestelling_datum < TRUNC (SYSDATE)
|
||||
AND b.bes_bestelling_status > 5
|
||||
AND b.bes_bestelling_key = bi.bes_bestelling_key
|
||||
leverdatum,
|
||||
(SELECT SUM (boi.bes_bestelopdr_item_aantalontv)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi, bes_bestelopdr_item boi
|
||||
WHERE -- boi.bes_bestelopdr_item_status in (6,7) AND
|
||||
b.bes_bestelling_key = bi.bes_bestelling_key
|
||||
AND boi.bes_bestelopdr_item_key = bi.bes_bestelopdr_item_key
|
||||
AND bi.bes_srtdeel_key = sd.bes_srtdeel_key)
|
||||
geleverd_gisteren
|
||||
geleverd
|
||||
FROM bes_srtdeel sd,
|
||||
bes_srtgroep g,
|
||||
bes_discipline bd,
|
||||
@@ -667,20 +693,16 @@ AS
|
||||
g.bes_srtgroep_omschrijving,
|
||||
sd.bes_srtdeel_nr, -- int. artikelnr
|
||||
sd.bes_srtdeel_omschrijving,
|
||||
substr(sd.bes_srtdeel_opmerking, 1, instr(sd.bes_srtdeel_opmerking, '*')-1) magazijn,
|
||||
bes.getsrtdeelprijs (sd.bes_srtdeel_key, NULL)
|
||||
srtdeel_prijs,
|
||||
bd.ins_discipline_omschrijving, -- int. catalogusnaam
|
||||
(SELECT SUM (bi.bes_bestelling_item_aantal)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi
|
||||
WHERE b.bes_bestelling_key = bi.bes_bestelling_key
|
||||
AND bi.bes_srtdeel_key = sd.bes_srtdeel_key)
|
||||
besteld,
|
||||
(SELECT SUM (bi.bes_bestelling_item_aantal)
|
||||
FROM bes_bestelling b, bes_bestelling_item bi
|
||||
WHERE b.bes_bestelling_datum < TRUNC (SYSDATE)
|
||||
(SELECT SUM (COALESCE(boi.bes_bestelopdr_item_aantal, bi.bes_bestelling_item_aantal))
|
||||
FROM bes_bestelling b, bes_bestelling_item bi, bes_bestelopdr_item boi
|
||||
WHERE boi.bes_bestelopdr_item_key(+) = bi.bes_bestelopdr_item_key
|
||||
AND b.bes_bestelling_key = bi.bes_bestelling_key
|
||||
AND bi.bes_srtdeel_key = sd.bes_srtdeel_key)
|
||||
besteld_gisteren
|
||||
besteld
|
||||
FROM bes_srtdeel sd,
|
||||
bes_srtgroep g,
|
||||
bes_discipline bd,
|
||||
@@ -693,6 +715,26 @@ AS
|
||||
ON extern.dkey = intern.dkey
|
||||
AND extern.bes_srtdeel_nr = intern.bes_srtdeel_nr;
|
||||
|
||||
|
||||
--
|
||||
-- Sync view
|
||||
--
|
||||
CREATE OR REPLACE VIEW pnbr_v_sync_alg_ruimte (
|
||||
alg_ruimte_key,
|
||||
alg_verdieping_key,
|
||||
cadlabel
|
||||
)
|
||||
AS
|
||||
SELECT r.alg_ruimte_key,
|
||||
r.alg_verdieping_key,
|
||||
decode (length(alg_verdieping_code), 1, '0' || alg_verdieping_code, alg_verdieping_code) || '.' ||
|
||||
decode (length(alg_ruimte_nr), 1, '00' || alg_ruimte_nr,
|
||||
2, '0' || alg_ruimte_nr,
|
||||
alg_ruimte_nr)
|
||||
FROM alg_v_aanwezigruimte r, alg_verdieping v
|
||||
WHERE r.alg_verdieping_key = v.alg_verdieping_key;
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_v_rap_dagstaat
|
||||
(
|
||||
res_rsv_ruimte_key,
|
||||
@@ -719,6 +761,7 @@ AS
|
||||
WHERE r.res_rsv_ruimte_key = w.res_rsv_ruimte_key
|
||||
AND w.res_kenmerk_key = k.res_kenmerk_key
|
||||
AND k.res_srtkenmerk_key = 1 -- zichtbaar op planbord
|
||||
AND k.res_activiteit_key = r.res_activiteit_key
|
||||
AND r.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
AND rro.res_ruimte_key = rr.res_ruimte_key
|
||||
AND fac.safe_to_number(w.res_kenmerkreservering_waarde) = 2
|
||||
@@ -943,9 +986,10 @@ AS
|
||||
|
||||
|
||||
|
||||
/* Formatted on 3/28/2012 3:05:36 PM (QP5 v5.136.908.31019) */
|
||||
CREATE OR REPLACE VIEW pnbr_v_rap_dagstaat_cat
|
||||
(
|
||||
datum,
|
||||
fclt_f_datum,
|
||||
dag,
|
||||
dagvweek,
|
||||
maand,
|
||||
@@ -979,7 +1023,10 @@ CREATE OR REPLACE VIEW pnbr_v_rap_dagstaat_cat
|
||||
bandopnamen
|
||||
)
|
||||
AS
|
||||
SELECT fclt_d_datum,
|
||||
SELECT TO_CHAR (TO_DATE (fclt_d_datum, 'dd-mm-yyyy'), 'yyyy-mm-dd')
|
||||
|| ' ('
|
||||
|| dagvweek
|
||||
|| ')',
|
||||
dag,
|
||||
dagvweek,
|
||||
maand,
|
||||
@@ -1012,9 +1059,8 @@ AS
|
||||
stoelen,
|
||||
bandopnamen
|
||||
FROM pnbr_v_rap_dagstaat_bron
|
||||
WHERE fclt_d_datum =
|
||||
TO_CHAR (fac.datumtijdplusuitvoertijd (SYSDATE, 1, 'DAGEN'),
|
||||
'dd-mm-yyyy');
|
||||
WHERE TO_DATE (fclt_d_datum, 'dd-mm-yyyy') BETWEEN TRUNC (SYSDATE - 1)
|
||||
AND TRUNC (SYSDATE + 10);
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_v_rap_dagstaat_even
|
||||
(
|
||||
@@ -1088,11 +1134,12 @@ AS
|
||||
WHERE activiteit = 'Evenement' OR aantalcatering > 0;
|
||||
|
||||
|
||||
BEGIN adm.systrackscript('$Workfile: pnbr.sql $', '$Revision: 1 $', 0); END;
|
||||
BEGIN adm.systrackscript('$Workfile: pnbr.sql $', '$Revision: 2 $', 0); END;
|
||||
/
|
||||
|
||||
BEGIN fac.registercustversion('PNBR', 2); END;
|
||||
BEGIN fac.registercustversion('PNBR', 4); END;
|
||||
/
|
||||
|
||||
|
||||
SET ECHO OFF
|
||||
SPOOL OFF
|
||||
|
||||
Reference in New Issue
Block a user