[ 
https://issues.apache.org/jira/browse/DERBY-6569?page=com.atlassian.jira.plugin.system.issuetabpanels:comment-tabpanel&focusedCommentId=14001534#comment-14001534
 ] 

Knut Anders Hatlen commented on DERBY-6569:
-------------------------------------------

Yes, I'm inclined to agree that it's a bug. Although some might call it an 
extension. And to further complicate things: CREATE FUNCTION didn't get support 
for the DETERMINISTIC keyword until Derby 10.5 (DERBY-3570), so all functions 
created by old applications are implicitly declared non-deterministic.

If we forbid non-deterministic function calls in NULLIF, as the standard 
requires, we should have a release note that tells users to rewrite affected 
applications either by redeclaring functions as deterministic if that's what 
they really are, or by restructuring their query so that the non-deterministic 
expression is not contained in the NULLIF expression. For example, the 
problematic expression in the issue description could be rewritten from 
{{SELECT NULLIF(INT(RANDOM()*2), 1) FROM SYS.SYSTABLES}} to {{SELECT NULLIF(R, 
1) FROM (SELECT INT(RANDOM()*2) FROM SYS.SYSTABLES) S(R)}}.

We could do that. I'm just a little worried about the backward compatibility 
given that all functions created with Derby 10.4 and earlier will be disallowed 
in NULLIF and require application changes.

> NULLIF may return incorrect results if first operand calls non-deterministic 
> function
> -------------------------------------------------------------------------------------
>
>                 Key: DERBY-6569
>                 URL: https://issues.apache.org/jira/browse/DERBY-6569
>             Project: Derby
>          Issue Type: Bug
>          Components: SQL
>    Affects Versions: 10.10.2.0
>            Reporter: Knut Anders Hatlen
>            Assignee: Knut Anders Hatlen
>         Attachments: d6569-1a.diff
>
>
> The SQL standard doesn't allow non-deterministic function calls in the 
> operands of NULLIF. Derby does however allow such calls, but the results may 
> not be as one might expect.
> Take an expression such as NULLIF(expr, 1). It shouldn't ever return 1. If 
> expr is 1, it should return NULL, and if expr is not 1, it should return expr.
> If expr contains a call to a non-deterministic function, it may actually end 
> up returning 1 sometimes:
> {noformat}
> ij> SELECT NULLIF(INT(RANDOM()*2), 1) FROM SYS.SYSTABLES;
> 1          
> -----------
> 1          
> 1          
> 1          
> NULL       
> NULL       
> NULL       
> NULL       
> 0          
> 1          
> NULL       
> NULL       
> 0          
> 0          
> NULL       
> 0          
> 1          
> 0          
> NULL       
> 1          
> 0          
> NULL       
> NULL       
> NULL       
> 23 rows selected
> {noformat}



--
This message was sent by Atlassian JIRA
(v6.2#6252)

Reply via email to