LOGI#42327 AUTO_STUFF-export/verwijderen bezoekers
svn path=/Customer/trunk/; revision=35609
This commit is contained in:
213
LOGI/logi.sql
213
LOGI/logi.sql
@@ -1481,101 +1481,67 @@ CREATE OR REPLACE PROCEDURE logi_select_auto_stuff (p_applname IN VARCHAR2,
|
||||
AS
|
||||
CURSOR cresbots -- Botsing tussen WP-RES door dezelfde aanvrager -> delete!
|
||||
IS
|
||||
SELECT '['
|
||||
|| rrr.res_reservering_key
|
||||
|| '/'
|
||||
|| rrr.res_rsv_ruimte_volgnr
|
||||
|| '] '
|
||||
SELECT '[' || rrr.res_reservering_key || '/' || rrr.res_rsv_ruimte_volgnr || '] '
|
||||
aanduiding,
|
||||
rrr.res_rsv_ruimte_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr,
|
||||
res_ruimte_opstelling rro,
|
||||
res_ruimte rr
|
||||
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr, res_ruimte_opstelling rro, res_ruimte rr
|
||||
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
AND rro.res_ruimte_key = rr.res_ruimte_key
|
||||
AND rr.res_discipline_key IN (621, 622, 623, 624, 625, 641)
|
||||
AND EXISTS
|
||||
(SELECT 1
|
||||
FROM res_v_aanwezigrsv_ruimte rrr2,
|
||||
res_ruimte_opstelling rro2,
|
||||
res_ruimte rr2
|
||||
WHERE rrr2.res_ruimte_opstel_key =
|
||||
rro2.res_ruimte_opstel_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr2, res_ruimte_opstelling rro2, res_ruimte rr2
|
||||
WHERE rrr2.res_ruimte_opstel_key = rro2.res_ruimte_opstel_key
|
||||
AND rro2.res_ruimte_key = rr2.res_ruimte_key
|
||||
AND rr2.res_discipline_key IN
|
||||
(621, 622, 623, 624, 625, 641)
|
||||
AND rrr2.res_rsv_ruimte_key >
|
||||
rrr.res_rsv_ruimte_key
|
||||
AND rrr2.res_rsv_ruimte_contact_key =
|
||||
rrr.res_rsv_ruimte_contact_key
|
||||
AND rrr2.res_rsv_ruimte_van <
|
||||
rrr.res_rsv_ruimte_tot
|
||||
AND rrr2.res_rsv_ruimte_tot >
|
||||
rrr.res_rsv_ruimte_van);
|
||||
AND rr2.res_discipline_key IN (621, 622, 623, 624, 625, 641)
|
||||
AND rrr2.res_rsv_ruimte_key > rrr.res_rsv_ruimte_key
|
||||
AND rrr2.res_rsv_ruimte_contact_key = rrr.res_rsv_ruimte_contact_key
|
||||
AND rrr2.res_rsv_ruimte_van < rrr.res_rsv_ruimte_tot
|
||||
AND rrr2.res_rsv_ruimte_tot > rrr.res_rsv_ruimte_van);
|
||||
|
||||
CURSOR creshori -- WP-RES te ver in de toekomst -> delete!
|
||||
IS
|
||||
SELECT '['
|
||||
|| rrr.res_reservering_key
|
||||
|| '/'
|
||||
|| rrr.res_rsv_ruimte_volgnr
|
||||
|| '] '
|
||||
SELECT '[' || rrr.res_reservering_key || '/' || rrr.res_rsv_ruimte_volgnr || '] '
|
||||
aanduiding,
|
||||
rrr.res_rsv_ruimte_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr,
|
||||
res_ruimte_opstelling rro,
|
||||
res_ruimte rr
|
||||
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr, res_ruimte_opstelling rro, res_ruimte rr
|
||||
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
AND rro.res_ruimte_key = rr.res_ruimte_key
|
||||
AND rr.res_discipline_key IN (621, 622, 623, 624, 625, 641)
|
||||
AND TRUNC (rrr.res_rsv_ruimte_van) > TRUNC (SYSDATE) + 15;
|
||||
|
||||
CURSOR cresduur -- WP-RES langer dan toegestane duur (1 uur) -> update!
|
||||
IS
|
||||
SELECT '['
|
||||
|| rrr.res_reservering_key
|
||||
|| '/'
|
||||
|| rrr.res_rsv_ruimte_volgnr
|
||||
|| '] '
|
||||
SELECT '[' || rrr.res_reservering_key || '/' || rrr.res_rsv_ruimte_volgnr || '] '
|
||||
aanduiding,
|
||||
rrr.res_rsv_ruimte_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr,
|
||||
res_ruimte_opstelling rro,
|
||||
res_ruimte rr
|
||||
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
FROM res_v_aanwezigrsv_ruimte rrr, res_ruimte_opstelling rro, res_ruimte rr
|
||||
WHERE rrr.res_ruimte_opstel_key = rro.res_ruimte_opstel_key
|
||||
AND rro.res_ruimte_key = rr.res_ruimte_key
|
||||
AND rr.res_discipline_key IN (621, 623)
|
||||
AND (rrr.res_rsv_ruimte_tot - rrr.res_rsv_ruimte_van) * 24 > 1;
|
||||
|
||||
CURSOR cart
|
||||
IS
|
||||
SELECT '['
|
||||
|| TO_CHAR (ra.res_rsv_ruimte_key)
|
||||
|| '/'
|
||||
|| TO_CHAR (ra.res_rsv_artikel_key)
|
||||
|| '] '
|
||||
SELECT '[' || TO_CHAR (ra.res_rsv_ruimte_key) || '/' || TO_CHAR (ra.res_rsv_artikel_key) || '] '
|
||||
aanduiding,
|
||||
ra.res_rsv_ruimte_key,
|
||||
ra.res_rsv_artikel_key,
|
||||
ra.res_artikel_key
|
||||
FROM res_rsv_artikel ra
|
||||
WHERE ra.res_status_bo_key = 2
|
||||
WHERE ra.res_status_bo_key = 2
|
||||
AND ra.res_rsv_artikel_dirtlevel = 0
|
||||
AND ra.res_rsv_artikel_verwijder IS NULL
|
||||
AND TRUNC (ra.res_rsv_artikel_levering + 1) < SYSDATE;
|
||||
|
||||
CURSOR cobj
|
||||
IS
|
||||
SELECT '['
|
||||
|| TO_CHAR (rd.res_rsv_ruimte_key)
|
||||
|| '/'
|
||||
|| TO_CHAR (rd.res_rsv_deel_key)
|
||||
|| '] '
|
||||
SELECT '[' || TO_CHAR (rd.res_rsv_ruimte_key) || '/' || TO_CHAR (rd.res_rsv_deel_key) || '] '
|
||||
aanduiding,
|
||||
rd.res_rsv_ruimte_key,
|
||||
rd.res_rsv_deel_key
|
||||
FROM res_rsv_deel rd
|
||||
WHERE rd.res_status_bo_key = 2
|
||||
WHERE rd.res_status_bo_key = 2
|
||||
AND rd.res_rsv_ruimte_key IS NOT NULL -- Geen parkeerplaatsen
|
||||
AND rd.res_rsv_deel_dirtlevel = 0
|
||||
AND rd.res_rsv_deel_verwijder IS NULL
|
||||
@@ -1583,15 +1549,26 @@ AS
|
||||
|
||||
CURSOR cres
|
||||
IS
|
||||
SELECT '[' || TO_CHAR (rrr.res_rsv_ruimte_key) || '] ' aanduiding,
|
||||
SELECT '[' || TO_CHAR (rrr.res_rsv_ruimte_key) || '] '
|
||||
aanduiding,
|
||||
rrr.res_rsv_ruimte_key
|
||||
FROM res_rsv_ruimte rrr
|
||||
WHERE rrr.res_status_bo_key = 2
|
||||
WHERE rrr.res_status_bo_key = 2
|
||||
AND rrr.res_ruimte_opstel_key IS NOT NULL -- Geen "roomservice"
|
||||
AND rrr.res_rsv_ruimte_dirtlevel = 0
|
||||
AND rrr.res_rsv_ruimte_verwijder IS NULL
|
||||
AND TRUNC (rrr.res_rsv_ruimte_tot + 1) < SYSDATE;
|
||||
|
||||
-- LOGI#42327: Verwijderen bezoekers bij afspraken >6 maanden oud!
|
||||
CURSOR cafspraak
|
||||
IS
|
||||
SELECT a.bez_afspraak_key
|
||||
FROM bez_afspraak a
|
||||
WHERE ADD_MONTHS (a.bez_afspraak_datum, 6) < SYSDATE
|
||||
AND EXISTS (SELECT 1 FROM bez_bezoekers WHERE bez_afspraak_key = a.bez_afspraak_key);
|
||||
|
||||
c_nu DATE := SYSDATE;
|
||||
c_txt_anoniem VARCHAR2 (200) := 'Geanonimiseerd';
|
||||
v_errorhint VARCHAR2 (1000);
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
@@ -1622,25 +1599,13 @@ BEGIN
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||||
v_errormsg :=
|
||||
v_errormsg
|
||||
|| ' ORACLE (error '
|
||||
|| oracle_err_num
|
||||
|| '/'
|
||||
|| oracle_err_mes
|
||||
|| ')';
|
||||
fac.writelog (p_applname,
|
||||
'E',
|
||||
r.aanduiding || v_errormsg,
|
||||
'RES_WP-botsing');
|
||||
v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
fac.writelog (p_applname, 'E', r.aanduiding || v_errormsg, 'RES_WP-botsing');
|
||||
COMMIT;
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
fac.writelog (p_applname,
|
||||
'S',
|
||||
'#RES_WP-botsing deletes: ' || TO_CHAR (v_count),
|
||||
'');
|
||||
fac.writelog (p_applname, 'S', '#RES_WP-botsing deletes: ' || TO_CHAR (v_count), '');
|
||||
|
||||
COMMIT;
|
||||
|
||||
@@ -1667,25 +1632,13 @@ BEGIN
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||||
v_errormsg :=
|
||||
v_errormsg
|
||||
|| ' ORACLE (error '
|
||||
|| oracle_err_num
|
||||
|| '/'
|
||||
|| oracle_err_mes
|
||||
|| ')';
|
||||
fac.writelog (p_applname,
|
||||
'E',
|
||||
r.aanduiding || v_errormsg,
|
||||
'RES_WP-horizon');
|
||||
v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
fac.writelog (p_applname, 'E', r.aanduiding || v_errormsg, 'RES_WP-horizon');
|
||||
COMMIT;
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
fac.writelog (p_applname,
|
||||
'S',
|
||||
'#RES_WP-horizon deletes: ' || TO_CHAR (v_count),
|
||||
'');
|
||||
fac.writelog (p_applname, 'S', '#RES_WP-horizon deletes: ' || TO_CHAR (v_count), '');
|
||||
|
||||
COMMIT;
|
||||
|
||||
@@ -1712,25 +1665,13 @@ BEGIN
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||||
v_errormsg :=
|
||||
v_errormsg
|
||||
|| ' ORACLE (error '
|
||||
|| oracle_err_num
|
||||
|| '/'
|
||||
|| oracle_err_mes
|
||||
|| ')';
|
||||
fac.writelog (p_applname,
|
||||
'E',
|
||||
r.aanduiding || v_errormsg,
|
||||
'RES_WP-tottijd');
|
||||
v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
fac.writelog (p_applname, 'E', r.aanduiding || v_errormsg, 'RES_WP-tottijd');
|
||||
COMMIT;
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
fac.writelog (p_applname,
|
||||
'S',
|
||||
'#RES_WP-tottijd updates: ' || TO_CHAR (v_count),
|
||||
'');
|
||||
fac.writelog (p_applname, 'S', '#RES_WP-tottijd updates: ' || TO_CHAR (v_count), '');
|
||||
|
||||
COMMIT;
|
||||
|
||||
@@ -1769,16 +1710,8 @@ BEGIN
|
||||
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);
|
||||
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;
|
||||
@@ -1808,16 +1741,8 @@ BEGIN
|
||||
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);
|
||||
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;
|
||||
@@ -1849,32 +1774,46 @@ BEGIN
|
||||
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);
|
||||
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;
|
||||
|
||||
COMMIT;
|
||||
|
||||
FOR rc IN cafspraak
|
||||
LOOP
|
||||
DELETE FROM fac_tracking
|
||||
WHERE fac_srtnotificatie_key IN (44, 361) -- BEZMAI/BEZUPD
|
||||
AND fac_tracking_refkey = rc.bez_afspraak_key;
|
||||
|
||||
DELETE FROM fac_tracking t
|
||||
WHERE t.fac_srtnotificatie_key IN (15, 16, 17, 18, 181, 581) -- BEZDON/BEZDO2/BEZOUT/BEZOU2/BEZBAD/BEZUNI
|
||||
AND EXISTS
|
||||
(SELECT 1
|
||||
FROM bez_bezoekers
|
||||
WHERE bez_afspraak_key = rc.bez_afspraak_key
|
||||
AND bez_bezoekers_key = t.fac_tracking_refkey);
|
||||
|
||||
DELETE FROM bez_bezoekers
|
||||
WHERE bez_afspraak_key = rc.bez_afspraak_key;
|
||||
|
||||
fac.trackaction ('#BEZUPD',
|
||||
rc.bez_afspraak_key,
|
||||
NULL,
|
||||
c_nu,
|
||||
c_txt_anoniem);
|
||||
END LOOP;
|
||||
|
||||
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,
|
||||
'E',
|
||||
'Proces AUTO_STUFF afgebroken!',
|
||||
v_errormsg);
|
||||
v_errormsg := 'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
fac.writelog (p_applname, 'E', 'Proces AUTO_STUFF afgebroken!', v_errormsg);
|
||||
COMMIT;
|
||||
END;
|
||||
/
|
||||
|
||||
Reference in New Issue
Block a user