488 lines
23 KiB
SQL
488 lines
23 KiB
SQL
-- Script containing customer specific configuration sql statements for ALLV: Allévo/Allité.
|
|
-- (c) 2007 Dijkoraad IT bv
|
|
-- $Revision: 12 $
|
|
-- $Modtime: 18-03-10 16:26 $
|
|
--
|
|
-- Support: +31 53 4800700
|
|
|
|
spool xallv.lst
|
|
set echo on
|
|
|
|
/* Formatted on 16-3-2010 10:44:04 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE VIEW allv_v_reserveringdetails
|
|
(
|
|
fclt_f_locatie,
|
|
hide_f_sort_datum_tijd,
|
|
hide_f_sort_ruimte,
|
|
hide_f_sort_resnr,
|
|
hide_f_sort_categorie,
|
|
fclt_f_datum,
|
|
resnr,
|
|
aantal,
|
|
ruimte,
|
|
van,
|
|
tot,
|
|
voorzieningen,
|
|
omschrijving,
|
|
opmerking
|
|
)
|
|
AS
|
|
SELECT l.alg_locatie_code locatie,
|
|
TO_CHAR (res_geg.res_reservering_van, 'YYYY-MM-DD HH24:MI')
|
|
sort_datum_tijd,
|
|
COALESCE (opstelalg.res_ruimte_nr,
|
|
ruimte_geg.alg_ruimte_aanduiding)
|
|
sort_ruimte,
|
|
rrr.res_reservering_key || '/' || rrr.res_rsv_ruimte_volgnr
|
|
sort_resnr,
|
|
res_geg.res_type sort_categorie,
|
|
TO_CHAR (res_geg.res_reservering_van, 'DD-MM-YYYY') datum,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
rrr.res_reservering_key
|
|
|| '/'
|
|
|| rrr.res_rsv_ruimte_volgnr
|
|
END)
|
|
resnr,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
TO_CHAR (rrr.res_rsv_ruimte_bezoekers)
|
|
END)
|
|
aantal,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
COALESCE (opstelalg.res_ruimte_nr,
|
|
ruimte_geg.alg_ruimte_aanduiding)
|
|
END)
|
|
ruimte,
|
|
TO_CHAR (res_geg.res_reservering_van, 'HH24:MI') van,
|
|
TO_CHAR (res_geg.res_reservering_tot, 'HH24:MI') tot,
|
|
(CASE
|
|
WHEN res_geg.aantal IS NOT NULL
|
|
THEN
|
|
TO_CHAR (res_geg.aantal)
|
|
|| ' * '
|
|
|| res_geg.res_voorziening
|
|
ELSE
|
|
res_geg.res_voorziening
|
|
END)
|
|
voorzieningen,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
res_rsv_ruimte_omschrijving
|
|
END)
|
|
omschrijving,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
res_rsv_ruimte_opmerking
|
|
END)
|
|
opmerking
|
|
FROM (SELECT '1R' AS res_type,
|
|
rrr.res_rsv_ruimte_key,
|
|
rro.res_ruimte_key,
|
|
rrr.res_rsv_ruimte_key AS res_item_key,
|
|
rrr.res_rsv_ruimte_van AS res_reservering_van,
|
|
rrr.res_rsv_ruimte_tot AS res_reservering_tot,
|
|
TO_NUMBER (NULL) AS aantal,
|
|
ro.res_opstelling_omschrijving AS res_voorziening,
|
|
rr.res_discipline_key AS res_ins_discipline_key,
|
|
rrr.res_status_bo_key,
|
|
TO_NUMBER (NULL) AS res_artikel_key,
|
|
rrr.res_rsv_ruimte_prijs AS prijs,
|
|
TO_NUMBER (NULL) AS stuks_prijs,
|
|
1 AS rsv_ruimte_aantal,
|
|
NULL AS artikelnummer,
|
|
'' AS artikel_groep,
|
|
fac.gettrackinguserkey ('RESAFM',
|
|
rrr.res_rsv_ruimte_key)
|
|
afmelder_key,
|
|
fac.gettrackingdate ('RESAFM', rrr.res_rsv_ruimte_key)
|
|
afmeld_datum
|
|
FROM res_v_aanwezigrsv_ruimte rrr,
|
|
res_ruimte_opstelling rro,
|
|
res_ruimte rr,
|
|
res_opstelling ro
|
|
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
|
AND rro.res_ruimte_key = rr.res_ruimte_key
|
|
AND rro.res_opstelling_key = ro.res_opstelling_key
|
|
AND rrr.res_rsv_ruimte_van BETWEEN TO_DATE (
|
|
TO_CHAR (
|
|
SYSDATE,
|
|
'yyyymmdd'
|
|
),
|
|
'yyyymmdd'
|
|
)
|
|
AND TO_DATE (
|
|
TO_CHAR (
|
|
SYSDATE + 10,
|
|
'yyyymmdd'
|
|
),
|
|
'yyyymmdd'
|
|
)
|
|
UNION ALL
|
|
SELECT '2V' AS res_type,
|
|
rrd.res_rsv_ruimte_key,
|
|
(SELECT rro.res_ruimte_key
|
|
FROM res_ruimte_opstelling rro
|
|
WHERE rrr.res_ruimte_opstel_key =
|
|
rro.res_ruimte_opstel_key)
|
|
AS res_ruimte_key,
|
|
rrd.res_rsv_deel_key AS res_item_key,
|
|
rrd.res_rsv_deel_van AS res_reservering_van,
|
|
rrd.res_rsv_deel_tot AS res_reservering_tot,
|
|
TO_NUMBER (NULL) AS aantal,
|
|
ID.ins_deel_omschrijving
|
|
|| ' ('
|
|
|| COALESCE (rd.res_deel_eenheid, '')
|
|
|| ')'
|
|
AS res_voorziening,
|
|
rd.res_discipline_key AS res_ins_discipline_key,
|
|
rrd.res_status_bo_key,
|
|
TO_NUMBER (NULL) AS res_artikel_key,
|
|
TO_NUMBER (NULL) AS prijs,
|
|
rd.res_deel_prijs AS stuks_prijs,
|
|
TO_NUMBER (NULL) AS rsv_ruimte_aantal,
|
|
NULL AS artikelnummer,
|
|
'' AS artikel_groep,
|
|
fac.gettrackinguserkey ('RESAFM', rrd.res_rsv_deel_key)
|
|
afmelder_key,
|
|
fac.gettrackingdate ('RESAFM', rrd.res_rsv_deel_key)
|
|
afmeld_datum
|
|
FROM res_v_aanwezigrsv_deel rrd,
|
|
res_v_aanwezigrsv_ruimte rrr,
|
|
res_deel rd,
|
|
ins_deel ID
|
|
WHERE rrd.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rrd.res_deel_key = rd.res_deel_key
|
|
AND rd.res_ins_deel_key = ID.ins_deel_key
|
|
AND rrd.res_rsv_deel_van BETWEEN TO_DATE (
|
|
TO_CHAR (
|
|
SYSDATE,
|
|
'yyyymmdd'
|
|
),
|
|
'yyyymmdd'
|
|
)
|
|
AND TO_DATE (
|
|
TO_CHAR (
|
|
SYSDATE + 10,
|
|
'yyyymmdd'
|
|
),
|
|
'yyyymmdd'
|
|
)
|
|
UNION ALL
|
|
SELECT '3C' AS res_type,
|
|
rra.res_rsv_ruimte_key,
|
|
(SELECT rro.res_ruimte_key
|
|
FROM res_ruimte_opstelling rro
|
|
WHERE rrr.res_ruimte_opstel_key =
|
|
rro.res_ruimte_opstel_key)
|
|
AS res_ruimte_key,
|
|
res_rsv_artikel_key AS res_item_key,
|
|
rra.res_rsv_artikel_levering AS res_reservering_van,
|
|
res_rsv_ruimte_tot AS res_reservering_tot,
|
|
rra.res_rsv_artikel_aantal AS aantal,
|
|
LTRIM (ra.res_artikel_omschrijving)
|
|
|| ' ('
|
|
|| COALESCE (ra.res_artikel_eenheid, '')
|
|
|| ')'
|
|
AS res_voorziening,
|
|
ra.res_discipline_key AS res_ins_discipline_key,
|
|
rra.res_status_bo_key,
|
|
ra.res_artikel_key AS res_artikel_key,
|
|
rra.res_rsv_artikel_prijs AS prijs,
|
|
ra.res_artikel_prijs / rra.res_rsv_artikel_aantal
|
|
AS stuks_prijs,
|
|
TO_NUMBER (NULL) AS rsv_ruimte_aantal,
|
|
ra.res_artikel_nr AS artikelnummer,
|
|
ra.res_artikel_groep AS artikel_groep,
|
|
fac.gettrackinguserkey ('RESAFM',
|
|
rra.res_rsv_artikel_key)
|
|
afmelder_key,
|
|
fac.gettrackingdate ('RESAFM', rra.res_rsv_artikel_key)
|
|
afmeld_datum
|
|
FROM res_v_aanwezigrsv_artikel rra,
|
|
res_v_aanwezigrsv_ruimte rrr,
|
|
res_artikel ra
|
|
WHERE rra.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rra.res_artikel_key = ra.res_artikel_key
|
|
AND rra.res_rsv_artikel_levering BETWEEN TO_DATE (
|
|
TO_CHAR (
|
|
SYSDATE,
|
|
'yyyymmdd'
|
|
),
|
|
'yyyymmdd'
|
|
)
|
|
AND TO_DATE (
|
|
TO_CHAR (
|
|
SYSDATE
|
|
+ 10,
|
|
'yyyymmdd'
|
|
),
|
|
'yyyymmdd'
|
|
)) res_geg,
|
|
res_rsv_ruimte rrr,
|
|
alg_v_ruimte_gegevens ruimte_geg,
|
|
( SELECT res_ruimte_opstel_key,
|
|
res_ruimte_nr,
|
|
MIN (alg_ruimte_key) alg_ruimte_key
|
|
FROM res_ruimte_opstelling rro,
|
|
res_alg_ruimte rar,
|
|
res_ruimte rr
|
|
WHERE rro.res_ruimte_key = rar.res_ruimte_key
|
|
AND rr.res_ruimte_key = rar.res_ruimte_key
|
|
AND rar.res_alg_ruimte_verwijder IS NULL
|
|
GROUP BY res_ruimte_opstel_key, res_ruimte_nr) opstelalg,
|
|
alg_locatie l
|
|
WHERE res_geg.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rrr.res_ruimte_opstel_key =
|
|
opstelalg.res_ruimte_opstel_key(+)
|
|
AND ruimte_geg.alg_ruimte_key =
|
|
COALESCE (rrr.alg_ruimte_key, opstelalg.alg_ruimte_key)
|
|
AND l.alg_locatie_key = ruimte_geg.alg_locatie_key
|
|
AND res_geg.res_status_bo_key < 5
|
|
/
|
|
|
|
/* Formatted on 16-3-2010 11:01:01 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE VIEW allv_v_rap_resweekdetails
|
|
(
|
|
fclt_f_locatie,
|
|
hide_f_sort_datum_tijd,
|
|
hide_f_sort_ruimte,
|
|
hide_f_sort_resnr,
|
|
hide_f_sort_categorie,
|
|
fclt_f_week,
|
|
dag,
|
|
resnr,
|
|
aantal,
|
|
ruimte,
|
|
van,
|
|
tot,
|
|
voorzieningen,
|
|
omschrijving,
|
|
opmerking
|
|
)
|
|
AS
|
|
SELECT l.alg_locatie_code locatie,
|
|
TO_CHAR (res_geg.res_reservering_van, 'YYYY-MM-DD HH24:MI')
|
|
sort_datum_tijd,
|
|
COALESCE (opstelalg.res_ruimte_nr,
|
|
ruimte_geg.alg_ruimte_aanduiding)
|
|
sort_ruimte,
|
|
rrr.res_reservering_key || '/' || rrr.res_rsv_ruimte_volgnr
|
|
sort_resnr,
|
|
res_geg.res_type sort_categorie,
|
|
'Week ' || TO_CHAR (res_geg.res_reservering_van, 'WW') week,
|
|
TO_CHAR (res_geg.res_reservering_van, 'DD/MM') dag,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
rrr.res_reservering_key
|
|
|| '/'
|
|
|| rrr.res_rsv_ruimte_volgnr
|
|
END)
|
|
resnr,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
TO_CHAR (rrr.res_rsv_ruimte_bezoekers)
|
|
END)
|
|
aantal,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
COALESCE (opstelalg.res_ruimte_nr,
|
|
ruimte_geg.alg_ruimte_aanduiding)
|
|
END)
|
|
ruimte,
|
|
TO_CHAR (res_geg.res_reservering_van, 'HH24:MI') van,
|
|
TO_CHAR (res_geg.res_reservering_tot, 'HH24:MI') tot,
|
|
(CASE
|
|
WHEN res_geg.aantal IS NOT NULL
|
|
THEN
|
|
TO_CHAR (res_geg.aantal)
|
|
|| ' * '
|
|
|| res_geg.res_voorziening
|
|
ELSE
|
|
res_geg.res_voorziening
|
|
END)
|
|
voorzieningen,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
res_rsv_ruimte_omschrijving
|
|
END)
|
|
omschrijving,
|
|
(CASE
|
|
WHEN res_geg.res_type <> '1R' AND rrr.alg_ruimte_key IS NULL
|
|
THEN
|
|
''
|
|
ELSE
|
|
res_rsv_ruimte_opmerking
|
|
END)
|
|
opmerking
|
|
FROM (SELECT '1R' AS res_type,
|
|
rrr.res_rsv_ruimte_key,
|
|
rro.res_ruimte_key,
|
|
rrr.res_rsv_ruimte_key AS res_item_key,
|
|
rrr.res_rsv_ruimte_van AS res_reservering_van,
|
|
rrr.res_rsv_ruimte_tot AS res_reservering_tot,
|
|
TO_NUMBER (NULL) AS aantal,
|
|
ro.res_opstelling_omschrijving AS res_voorziening,
|
|
rr.res_discipline_key AS res_ins_discipline_key,
|
|
rrr.res_status_bo_key,
|
|
TO_NUMBER (NULL) AS res_artikel_key,
|
|
rrr.res_rsv_ruimte_prijs AS prijs,
|
|
TO_NUMBER (NULL) AS stuks_prijs,
|
|
1 AS rsv_ruimte_aantal,
|
|
NULL AS artikelnummer,
|
|
'' AS artikel_groep,
|
|
fac.gettrackinguserkey ('RESAFM',
|
|
rrr.res_rsv_ruimte_key)
|
|
afmelder_key,
|
|
fac.gettrackingdate ('RESAFM', rrr.res_rsv_ruimte_key)
|
|
afmeld_datum
|
|
FROM res_v_aanwezigrsv_ruimte rrr,
|
|
res_ruimte_opstelling rro,
|
|
res_ruimte rr,
|
|
res_opstelling ro
|
|
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
|
AND rro.res_ruimte_key = rr.res_ruimte_key
|
|
AND rro.res_opstelling_key = ro.res_opstelling_key
|
|
AND rrr.res_rsv_ruimte_van BETWEEN SYSDATE - 7
|
|
AND SYSDATE + 14
|
|
AND TO_CHAR (rrr.res_rsv_ruimte_van, 'WW') IN
|
|
(TO_CHAR (SYSDATE, 'WW'),
|
|
TO_CHAR (SYSDATE + 7, 'WW'))
|
|
UNION ALL
|
|
SELECT '2V' AS res_type,
|
|
rrd.res_rsv_ruimte_key,
|
|
(SELECT rro.res_ruimte_key
|
|
FROM res_ruimte_opstelling rro
|
|
WHERE rrr.res_ruimte_opstel_key =
|
|
rro.res_ruimte_opstel_key)
|
|
AS res_ruimte_key,
|
|
rrd.res_rsv_deel_key AS res_item_key,
|
|
rrd.res_rsv_deel_van AS res_reservering_van,
|
|
rrd.res_rsv_deel_tot AS res_reservering_tot,
|
|
TO_NUMBER (NULL) AS aantal,
|
|
ID.ins_deel_omschrijving
|
|
|| ' ('
|
|
|| COALESCE (rd.res_deel_eenheid, '')
|
|
|| ')'
|
|
AS res_voorziening,
|
|
rd.res_discipline_key AS res_ins_discipline_key,
|
|
rrd.res_status_bo_key,
|
|
TO_NUMBER (NULL) AS res_artikel_key,
|
|
TO_NUMBER (NULL) AS prijs,
|
|
rd.res_deel_prijs AS stuks_prijs,
|
|
TO_NUMBER (NULL) AS rsv_ruimte_aantal,
|
|
NULL AS artikelnummer,
|
|
'' AS artikel_groep,
|
|
fac.gettrackinguserkey ('RESAFM', rrd.res_rsv_deel_key)
|
|
afmelder_key,
|
|
fac.gettrackingdate ('RESAFM', rrd.res_rsv_deel_key)
|
|
afmeld_datum
|
|
FROM res_v_aanwezigrsv_deel rrd,
|
|
res_v_aanwezigrsv_ruimte rrr,
|
|
res_deel rd,
|
|
ins_deel ID
|
|
WHERE rrd.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rrd.res_deel_key = rd.res_deel_key
|
|
AND rd.res_ins_deel_key = ID.ins_deel_key
|
|
AND rrd.res_rsv_deel_van BETWEEN SYSDATE - 7
|
|
AND SYSDATE + 14
|
|
AND TO_CHAR (rrd.res_rsv_deel_van, 'WW') IN
|
|
(TO_CHAR (SYSDATE, 'WW'),
|
|
TO_CHAR (SYSDATE + 7, 'WW'))
|
|
UNION ALL
|
|
SELECT '3C' AS res_type,
|
|
rra.res_rsv_ruimte_key,
|
|
(SELECT rro.res_ruimte_key
|
|
FROM res_ruimte_opstelling rro
|
|
WHERE rrr.res_ruimte_opstel_key =
|
|
rro.res_ruimte_opstel_key)
|
|
AS res_ruimte_key,
|
|
res_rsv_artikel_key AS res_item_key,
|
|
rra.res_rsv_artikel_levering AS res_reservering_van,
|
|
res_rsv_ruimte_tot AS res_reservering_tot,
|
|
rra.res_rsv_artikel_aantal AS aantal,
|
|
LTRIM (ra.res_artikel_omschrijving)
|
|
|| ' ('
|
|
|| COALESCE (ra.res_artikel_eenheid, '')
|
|
|| ')'
|
|
AS res_voorziening,
|
|
ra.res_discipline_key AS res_ins_discipline_key,
|
|
rra.res_status_bo_key,
|
|
ra.res_artikel_key AS res_artikel_key,
|
|
rra.res_rsv_artikel_prijs AS prijs,
|
|
ra.res_artikel_prijs / rra.res_rsv_artikel_aantal
|
|
AS stuks_prijs,
|
|
TO_NUMBER (NULL) AS rsv_ruimte_aantal,
|
|
ra.res_artikel_nr AS artikelnummer,
|
|
ra.res_artikel_groep AS artikel_groep,
|
|
fac.gettrackinguserkey ('RESAFM',
|
|
rra.res_rsv_artikel_key)
|
|
afmelder_key,
|
|
fac.gettrackingdate ('RESAFM', rra.res_rsv_artikel_key)
|
|
afmeld_datum
|
|
FROM res_v_aanwezigrsv_artikel rra,
|
|
res_v_aanwezigrsv_ruimte rrr,
|
|
res_artikel ra
|
|
WHERE rra.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rra.res_artikel_key = ra.res_artikel_key
|
|
AND rra.res_rsv_artikel_levering BETWEEN SYSDATE - 7
|
|
AND SYSDATE + 14
|
|
AND TO_CHAR (rra.res_rsv_artikel_levering, 'WW') IN
|
|
(TO_CHAR (SYSDATE, 'WW'),
|
|
TO_CHAR (SYSDATE + 7, 'WW'))) res_geg,
|
|
res_rsv_ruimte rrr,
|
|
alg_v_ruimte_gegevens ruimte_geg,
|
|
( SELECT res_ruimte_opstel_key,
|
|
res_ruimte_nr,
|
|
MIN (alg_ruimte_key) alg_ruimte_key
|
|
FROM res_ruimte_opstelling rro,
|
|
res_alg_ruimte rar,
|
|
res_ruimte rr
|
|
WHERE rro.res_ruimte_key = rar.res_ruimte_key
|
|
AND rr.res_ruimte_key = rar.res_ruimte_key
|
|
AND rar.res_alg_ruimte_verwijder IS NULL
|
|
GROUP BY res_ruimte_opstel_key, res_ruimte_nr) opstelalg,
|
|
alg_locatie l
|
|
WHERE res_geg.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rrr.res_ruimte_opstel_key =
|
|
opstelalg.res_ruimte_opstel_key(+)
|
|
AND ruimte_geg.alg_ruimte_key =
|
|
COALESCE (rrr.alg_ruimte_key, opstelalg.alg_ruimte_key)
|
|
AND l.alg_locatie_key = ruimte_geg.alg_locatie_key
|
|
AND res_geg.res_status_bo_key < 5
|
|
/
|
|
|
|
BEGIN fac.registercustversion('ALLV', 2); END;
|
|
/
|
|
|
|
COMMIT;
|
|
spool off
|