Files
Customer/PHBF/phbf.sql
Maarten van der Heide f754e29b0f IVET#73753 Sleepbaar thema/Bugfix(es) trigger
svn path=/Customer/trunk/; revision=56985
2022-08-24 08:12:41 +00:00

108 lines
3.6 KiB
SQL

--
-- $Id$
--
-- Script containing customer specific db-configuration for IVET.
DEFINE thisfile = 'PHBF.SQL'
DEFINE dbuser = '^PHBF'
SET ECHO ON
SET DEFINE ON
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
COLUMN fcltcusttxt NEW_VALUE fcltcusttxt NOPRINT;
WHENEVER SQLERROR CONTINUE;
SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL;
SPOOL &fcltlogfile
WHENEVER SQLERROR EXIT;
SELECT adm.checkscriptcust('&dbuser') AS fcltcusttxt FROM DUAL;
WHENEVER SQLERROR CONTINUE;
---------------------------------------
PROMPT &fcltcusttxt
---------------------------------------
SET DEFINE OFF
------ payload begin ------
/* Formatted on 2-3-2010 21:00:14 (QP5 v5.115.810.9015) */
CREATE OR REPLACE VIEW phbf_v_thema_vloerafw
(
alg_ruimte_key,
waarde,
waarde_key
)
AS
SELECT a.alg_ruimte_key,
COALESCE (b.vloerafw, '[Onbekend]'),
COALESCE (b.vloerafw_key, -1)
FROM (SELECT r.alg_ruimte_key
FROM alg_v_aanwezigruimte r) a
LEFT JOIN
(SELECT ok.alg_onrgoed_key,
ud.fac_usrdata_omschr vloerafw,
ud.fac_usrdata_key vloerafw_key
FROM alg_onrgoedkenmerk ok, fac_usrdata ud
WHERE ok.alg_kenmerk_key = 1020 -- Vloerafwerking
AND ok.alg_onrgoed_niveau = 'R'
AND ok.alg_onrgoedkenmerk_verwijder IS NULL
AND ok.alg_onrgoedkenmerk_waarde =
ud.fac_usrdata_key) b
ON a.alg_ruimte_key = b.alg_onrgoed_key
UNION ALL
SELECT NULL,
ud.fac_usrdata_omschr vloerafw,
ud.fac_usrdata_key vloerafw_key
FROM fac_usrdata ud
WHERE ud.fac_usrtab_key = 21
AND NOT EXISTS
(SELECT 1
FROM alg_onrgoedkenmerk ok
WHERE ok.alg_kenmerk_key = 1020 -- Vloerafwerking
AND ok.alg_onrgoedkenmerk_waarde =
ud.fac_usrdata_key);
/* Formatted on 23-8-2022 18:25:45 (QP5 v5.136.908.31019) */
CREATE OR REPLACE TRIGGER phbf_t_thema_vloerafw_i_iu
INSTEAD OF INSERT OR UPDATE
ON phbf_v_thema_vloerafw
BEGIN
IF UPDATING -- oude hard weggooien; dus DELETE (lekker opruimen)!
THEN
DELETE FROM alg_onrgoedkenmerk
WHERE alg_onrgoed_key = :new.alg_ruimte_key
AND alg_onrgoed_niveau = 'R'
AND alg_kenmerk_key = 1020
AND (alg_onrgoedkenmerk_waarde IS NULL -- IVET#73753/73776: Zou nooit NULL mogen zijn, maar was dat ergens wel!?
OR fac.safe_to_number (alg_onrgoedkenmerk_waarde) <> :new.waarde_key);
END IF;
BEGIN
IF :new.waarde_key <> -1
THEN
INSERT INTO alg_onrgoedkenmerk (alg_onrgoed_key,
alg_onrgoed_niveau,
alg_kenmerk_key,
alg_onrgoedkenmerk_waarde)
VALUES (:new.alg_ruimte_key,
'R',
1020,
:new.waarde_key);
END IF;
EXCEPTION
WHEN DUP_VAL_ON_INDEX -- was al aanwezig
THEN
NULL;
END;
END;
/
------ payload end ------
SET DEFINE OFF
BEGIN adm.systrackscriptId ('$Id$', 0); END;
/
COMMIT;
SET ECHO OFF
SPOOL OFF
SET DEFINE ON
PROMPT Logfile of this upgrade is: &fcltlogfile