--#SET TERMINATOR !
CREATE TRIGGER EMPSCREDIT
NO CASCADE BEFORE INSERT ON EMP_SCREEN_EDIT
REFERENCING NEW AS n
FOR EACH ROW MODE DB2SQL
BEGIN ATOMIC
DECLARE reason VARCHAR(68);
SET reason
= CASE WHEN LENGTH(RTRIM(TRANSLATE(EMPNO, '*', ' 0123456789'))) <> 0
THEN '130 INVALID EMP NUMBER - MUST BE NUMERIC '
WHEN FIRSTNME <= ' '
THEN '146 FIRSTNME IS MISSED'
WHEN LENGTH(RTRIM(TRANSLATE(FIRSTNME, '*', '
ABCDEFGHIGKLMNOPQRSTUVWXYZ'))) <> 0
THEN '146 INVALID FIRSTNME MUST BE ALPHABETIC'
WHEN LENGTH(RTRIM(TRANSLATE(MIDINIT, '*', '
ABCDEFGHIGKLMNOPQRSTUVWXYZ'))) <> 0
THEN '154 INVALID MIDINIT MUST BE SPACE OR ALPHABETIC'
WHEN LASTNAME <= ' '
THEN '165 LASTNAME IS MISSED'
WHEN LENGTH(RTRIM(TRANSLATE(FIRSTNME, '*', '
ABCDEFGHIGKLMNOPQRSTUVWXYZ'))) <> 0
THEN '165 INVALID LASTNAME MUST BE ALPHABETIC'
WHEN WORKDEPT NOT IN ('A01','BO1','C01','D11','D21','E01','E11',
'E21')
THEN '177 INVALID DEPATRMENT, VALID --> A01,B01,C01,D11,D21,E01,
E11,E21'
WHEN JOB NOT IN('ANALYST ','CLERK ','DESIGNER','FEILDREP',
'MANAGER ‘OPERATOR','PRES ','SALESREP')
THEN '328 INVALID JOB DESCRIPTION'
WHEN EDLEVEL NOT IN(12,14,15,16,17,18,19,20)
THEN '345 INVALID EDUCATION LEVEL'
WHEN SEX NOT IN ('M','F')
THEN '355 INVALID GENDER'
WHEN SALARY = 0
THEN '422 INVALID SALARY, MUST BE GREATER THAN ZERO'
WHEN HIREDATE <= BIRTHDATE
THEN '292 HIREDATE MUST GREATER THAN BITHDATE'
WHEN YEAR(HIREDATE) - YEAR(BIRTHDATE) < 18
THEN '292 HIRED EMPLOYEE MUST 18 OR OLDER'
ELSE NULL END;
IF reason IS NOT NULL THEN
SIGNAL SQLSTATE '7500S' (reason);
END IF;
END!
Also there are date fields which are not part of check in edit.
When date field is wrong system is genereting message:
The syntax of the string representation of a datetime value is incorrect
sqlcode: -180 .
Is it possible to process this error code in the trigger and populate reason
field.i
--
Message posted via DBMonster.com
http://www.dbmonster.com/Uwe/Forums.aspx/ibm-db2/200807/1
Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab
• User query joins to table function - sends DML or DDL statement to be
executed.
• Table function calls stored procedure - sends statement to be executed.
• Stored procedure executes statement.
• Stored procedure returns SQLCODE of statement to the table function.
• Table function joins back to the user query a single-row table with two
columns: The
SQLCODE and the original input statement.
--#SET TERMINATOR !
CREATE PROCEDURE execute_immediate (IN in_stmt VARCHAR(1000)
,OUT out_sqlcode INTEGER)
LANGUAGE SQL
MODIFIES SQL DATA
BEGIN
DECLARE sqlcode INTEGER;
DECLARE EXIT HANDLER FOR sqlexception
SET out_sqlcode = sqlcode;
EXECUTE IMMEDIATE in_stmt;
SET out_sqlcode = sqlcode;
RETURN;
END!
--#SET TERMINATOR !
CREATE FUNCTION execute_immediate (in_stmt VARCHAR(1000))
RETURNS TABLE (sqltext VARCHAR(1000)
,sqlcode INTEGER)
LANGUAGE SQL
MODIFIES SQL DATA
BEGIN ATOMIC
DECLARE out_sqlcode INTEGER;
CALL execute_immediate(in_stmt, out_sqlcode);
RETURN VALUES (in_stmt, out_sqlcode);
END!
Then i tryied to test it:
select 1,stm.sqlcode as sqlcode, CHAR(stm.sqltext,100) as sqltext
from sysibm.sysdummy1
,table(execute_immediate('select * from emp_screen_edit')) as stm;
and got the followung error:
sqlstate: 429BL
The function "EXECUTE_IMMEDIATE" (specific "SQL080715180239600") modifies SQL
data and is invoked in an illegal context. Reason code = "3
3. The table function is preceded by a table reference which is not
referenced by a function argument.
Serge please help.
Thank's in advance
Leny G.
Serge Rielau wrote:
>> I have an edit trigger:
>>
>[quoted text clipped - 52 lines]
>> Is it possible to process this error code in the trigger and populate reason
>> field.i
>
>In DB2 for LUW not directly. To do things like condition handling inside
>of a trigger push the logic into a stored procedure and CALL that.
>The SQL Procedure has the full power of SQL PL at its disposal.
>
>Cheers
>Serge
>
--
WITH temp1 AS
(SELECT tabschema
,tabname
FROM syscat.tables
WHERE tabschema = 'FRED'
AND type = 'S'
AND status = 'C'
AND tabname LIKE '%DEPT%'
)
SELECT CHAR(tab.tabname,20) AS tabname
,stm.sqlcode AS sqlcode
,CHAR(stm.sqltext,100) AS sqltext
FROM temp1 AS tab
,TABLE(execute_immediate(
'REFRESH TABLE ' ||
RTRIM(tab.tabschema) || '.' || tab.tabname
))AS stm
ORDER BY tab.tabname
WITH UR;
>>> I have an edit trigger:
>>>
>[quoted text clipped - 8 lines]
>>Cheers
>>Serge
--
Message posted via http://www.dbmonster.com
CALL execute_immediate('select * FROM FAMILY',out_sqlcode);
CALL execute_immediate('select * FROM FAMILY',out_sqlcode)
SQL0206N "OUT_SQLCODE" is not valid in the context where it is used.
SQLSTATE=42703
sqlcode: -206
lenygold wrote:
>Here is exable from book how to use this UDF/SP COMBO:
>
>WITH temp1 AS
>(SELECT tabschema
>,tabname
>FROM syscat.tables
>WHERE tabschema = 'FRED'
>AND type = 'S'
>AND status = 'C'
>AND tabname LIKE '%DEPT%'
>)
>SELECT CHAR(tab.tabname,20) AS tabname
>,stm.sqlcode AS sqlcode
>,CHAR(stm.sqltext,100) AS sqltext
>FROM temp1 AS tab
>,TABLE(execute_immediate(
>'REFRESH TABLE ' ||
>RTRIM(tab.tabschema) || '.' || tab.tabname
>))AS stm
>ORDER BY tab.tabname
>WITH UR;
>
>>Thank you very much SERGE for your help.
>>I found example in Graeme Birchall COOKBOOK wich i think exactly what i need
>[quoted text clipped - 57 lines]
in your trigger this presumably looks like this:
CREATE TRIGGER ....
BEGIN ATOMIC
DECLARE out_sqlcode INTEGER;
CALL execute_immediate('....', out_sqlcode);
END
@
--#SET TERMINATOR !
CREATE TRIGGER EMPSCREDIT
AFTER INSERT ON EMP_SCREEN_EDIT
REFERENCING NEW AS n
FOR EACH ROW MODE DB2SQL
BEGIN ATOMIC
DECLARE reason VARCHAR(68);
DECLARE OUT_SQLCODE INTEGER;
CALL execute_immediate('select hiredate from EMP_SCREEN_EDIT',OUT_SQLCODE)
;
SET reason
= CASE WHEN OUT_SQLCODE <> 0
THEN '292 INVALID HIREDATE'
insert with wrong hiredate:
insert into EMP_SCREEN_EDIT
values(USER,CURRENT_TIMESTAMP,'000900','LENNY','D','GOLD','A01','99/27/1999',
'MANAGER',12, 'M','11/02/1953',140000.00,900.00,3000.00);
i expect - '292 INVALID HIREDATE'
but i got - sqlcode: -181
The string representation of a datetime value is out of range.
It din't work.???
Serge Rielau wrote:
>> I TRIED ONLY SP AND ALSO AN ERROR:
>>
>[quoted text clipped - 4 lines]
>> SQLSTATE=42703
>> sqlcode: -206
>Of course out_sqlcode is not defined.
>
>in your trigger this presumably looks like this:
>
>CREATE TRIGGER ....
> BEGIN ATOMIC
> DECLARE out_sqlcode INTEGER;
> CALL execute_immediate('....', out_sqlcode);
> END
>@
>
--
When you insert into a DATE column. DB2 will aggressively(!) ensure the
date is sane. That is this error is being raised before your trigger is
being called.
Now clearly DB2 will not allow bad dates into the table (which is what
you rely on with your AFTER trigger.
But DB2 will also not allow bad dates to flow through it's runtime code.
Thus even a BEFORE trigger will do you no good.
There are three ways to do what you want to do on the database side:
* Use an instead of trigger on a view where the view maps the DATe in
the table to a VARCHAR and the INSTEAD OF trigger maps it back
That is a horrible idea
* Store a string in the database instead of a date.
Preferably in a yyyymmdd format, so you can do comparisons on it.
That is slightly less horrid
* Use a stored procedure instead of an INSERT to drive your
modification.
There are users who do this on principle.
"No SQL other than a CALL in my app"
This way your proc can do everything it wants to and you
insert once you are satisfied.
Now, all this can be avoided if you shift your thinking:
DB2 gave you a perfectly good error message saying exactly what you
wanted to say. Why not use it? Let the application catch the -181 (or
the associated SQLSTATE which is likely ANSI Standard)
Cheers
Serge
Using triggers for edit saved us 70% coding time and also made available
all best DB2 features insted 1000's lines of COBOL coding.
So if i can not use triggers to overlay system generated error message,
how can I resolve this issue. May be Constraint on data fields will help?
Thahk You again Serge. I learn a lot new things on this board.
Date is invalid.
--