DB2 - Problem description
| Problem IC72985 | Status: Closed |
IF OR CASE STATEMENT MAY FAIL WITH SQL0206N WHEN IT CONTAINS A SINGLE SET STATEMENT | |
| product: | |
DB2 FOR LUW / DB2FORLUW / 970 - DB2 | |
| Problem description: | |
An IF or CASE statement may fail with SQL0206N when each clause
contains a single SET statement with the same target (left-hand
side) variable, and the right-hand side of one or more of the
SET statements references a compiled SQL function.
For example, the following UDF fails with SQL0206N when it's
used in the following IF statement:
========
set serveroutput on %
create or replace function test (inout p_msg varchar(256))
returns varchar(256)
begin
declare v_msg varchar(256);
set v_msg = 'Hello';
return v_msg;
end %
begin
declare v_msg1 varchar(256);
declare v_msg2 varchar(256);
set v_msg1 = 'ABCDE';
call dbms_output.put_line('v_msg1 = ' || v_msg1);
if (v_msg1 is null) or (v_msg1 = 'NOTHING') then
set v_msg2 = 'EMPTY';
else
-- set v_msg2 = 'DUMMY';
set v_msg2 = test(v_msg1);
end if;
call dbms_output.put_line ('v_msg1 = ' || v_msg1);
call dbms_output.put_line ('v_msg2 = ' || v_msg2);
end %
======== | |
| Problem Summary: | |
****************************************************************
* USERS AFFECTED: *
* DB2 UDB Version 9.7 *
****************************************************************
* PROBLEM DESCRIPTION: *
* An IF or CASE statement may fail with SQL0206N when each *
* clause contains a single SET statement with the same target *
* (left-hand *
* side) variable, and the right-hand side of one or more of *
* the SET statements references a compiled SQL function. *
* For example, the following UDF fails with SQL0206N when it's *
* used in the following IF statement: *
* ======== *
* set serveroutput on % *
* *
* create or replace function test (inout p_msg varchar(256)) *
* returns varchar(256) *
* begin *
* declare v_msg varchar(256); *
* set v_msg = 'Hello'; *
* return v_msg; *
* end % *
* *
* begin *
* declare v_msg1 varchar(256); *
* declare v_msg2 varchar(256); *
* *
* set v_msg1 = 'ABCDE'; *
* call dbms_output.put_line('v_msg1 = ' || v_msg1); *
* if (v_msg1 is null) or (v_msg1 = 'NOTHING') then *
* set v_msg2 = 'EMPTY'; *
* else *
* -- set v_msg2 = 'DUMMY'; *
* set v_msg2 = test(v_msg1); *
* end if; *
* call dbms_output.put_line ('v_msg1 = ' || v_msg1); *
* call dbms_output.put_line ('v_msg2 = ' || v_msg2); *
* end % *
* ======== *
****************************************************************
* RECOMMENDATION: *
* Upgrade to Version 9.7 FixPack 4. *
**************************************************************** | |
| Local Fix: | |
Adding another SET statement which doesn't refer to a compiled SQL function will avoid the problem. The above example will work fine by enabling the comment line "set v_msg2 = 'DUMMY';". | |
| available fix packs: | |
DB2 Version 9.7 Fix Pack 4 for Linux, UNIX, and Windows | |
| Solution | |
Problem was first fixed in DB2 UDB Version 9.7 FixPack 4. | |
| Workaround | |
not known / see Local fix | |
| Timestamps | |
Date - problem reported : Date - problem closed : Date - last modified : | 02.12.2010 05.05.2011 05.05.2011 |
| Problem solved at the following versions (IBM BugInfos) | |
9.7.FP4 | |
| Problem solved according to the fixlist(s) of the following version(s) | |
| 9.7.0.4 |
|