Discussion:
[Firebird-devel] Literals in CASE expression
Pavel Cisar
2016-01-05 13:31:50 UTC
Permalink
Hi all,

We have an annoying little problem. The visible manifestation is that
literals in CASE expressions could be padded with spaces.

Here is simplified example:

set term ^;
create procedure tmp_sp(pParam integer)
returns (selectionIf varchar(40), selectionCase varchar(40))
as
declare variable color varchar(10);
begin
if (pParam=1) then color='red';
else if (pParam=2) then color='yellow';
selectionIf='You have selected '||:color||' bag';

color=case :pParam when 1 then 'red' when 2 then 'yellow' end;
selectionCase='You have selected '||:color||' bag';
suspend;
end
^
set term ;^

select * from tmp_sp(1);

SELECTIONIF SELECTIONCASE
=========================== ============================
You have selected red bag You have selected red bag

drop procedure tmp_sp;
commit;

---

Padding with spaces is not a bug! Spaces are there because string
literals are CHARs, NOT VARCHARs. This is required by SQL standard.

Relevant except from SQL standard:

5 Lexical elements

5.3 <literal>
Syntax Rules
...
15) The declared type of a <character string literal> is fixed-length
character string. The length of a <character string literal> is the
number of <character representation>s that it contains.

...

6 Scalar expressions

6.11 <case expression>
Syntax Rules
...
7) The declared type of a <case specification> is determined by applying
Subclause 9.3, ‘‘Data types of results of aggregations’’, to the declared
types of all <result expression>s in the <case specification>.


9 Additional common rules

9.3 Data types of results of aggregations
Syntax Rules
...
3) Case:
a) If any of the data types in DTS is character string, then:
...
iii) Case:
1) If any of the data types in DTS is character large object string,
then the result data type is character large object string with
maximum length in characters equal to the maximum of the lengths in
characters and maximum lengths in characters of the data types in DTS.

2) If any of the data types in DTS is variable-length character string,
then the result data type is variable-length character string with
maximum length in characters equal to the maximum of the lengths in
characters and maximum lengths in characters of the data types in DTS.

3) Otherwise, the result data type is fixed-length character string with
length in characters equal to the maximum of the lengths in characters
of the data types in DTS.

----

To sum it up, standard dictates that literals are CHARs, aggregated
values has length of longest one and because CHARs are padded with
spaces to declared length, we have such stupid output in CASE. Sure, it
could be easily "fixed" with CAST or TRIM, but it's extremely annoying
to do so. And if there is any real world case when CHAR is the right
type for literals and VARCHAR the wrong one, I can't see it and would be
glad to be enlightened by someone else.

You may ask why I'm raising this issue here when Firebird's policy is to
follow SQL standard whenever possible (even with stupid requirements),
so annoying or not, we have to live with it. BUT... other databases are
not so strict here, break the stupid standard requirement and use
VARCHAR instead CHAR, for example:

MS SQLServer 2012:

SELECT 'a'+case 1 when 1 then '1 ' when 2 then '22222222222' end+'b'
FROM [SCM].[dbo].[SERVERID]
----
a1 b
(1 row(s) affected)


mySQL 5.6:

select concat('a', case 1 when 1 then '1 ' when 2 then '22222222222'
end, 'b') from tmp;
| concat('a', case 1 when 1 then '1 ' when 2 then '22222222222' end, 'b') |
|-------------------------------------------------------------------|
| a1 b |


oracle (not sure which version, provided by sqlZoo.net):

SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
FROM world
'A'||CASE1WHE..
a1 b
...


PostgreSQL (not sure which version, provided by sqlZoo.net):

select concat('a', case 1 when 1 then '1 ' when 2 then '22222222222'
end, 'b') from world
concat
a1 b
...


db2 (not sure which version, provided by sqlZoo.net):

SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
FROM world
1
a1 b
...


So Firebird stands out from the flock here with:

SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
FROM rdb$database;
CONCATENATION
=============
a1 b

---

So Firebird behavior is even more annoying when you (have to or was used
to) work with other databases.

My question is: Could we sacrifice the standard compliance a little bit
by using VARCHAR instead CHAR (length rules remain the same!) as others
do? Because following the standard here really doesn't work in our favor
in this particular case.

My personal vote is for relaxing the rules and use VARCHAR. What is your
opinion?

best regards
Pavel Cisar
IBPhoenix
Carlos H. Cantu
2016-01-05 14:08:16 UTC
Permalink
I start wondering if nowadays, saying that a RDBMS "complies to the SQL
Standard" is seem by the users as a "plus".

Most of the time, I saw this as a good way to say: "Ok, Firebird is
Standard compliant, so you can move easily from another RDBMS to it".
But seems that all the others RDBMS don't care much about following
the SQL Standard, so I wonder if trying to follow it is of any good
nowadays.

Regarding your suggestion, I would vote for using VARCHAR too.

[]s
Carlos
http://www.firebirdnews.org
FireBase - http://www.FireBase.com.br

PC> Hi all,

PC> We have an annoying little problem. The visible manifestation is that
PC> literals in CASE expressions could be padded with spaces.

PC> Here is simplified example:

PC> set term ^;
PC> create procedure tmp_sp(pParam integer)
PC> returns (selectionIf varchar(40), selectionCase varchar(40))
PC> as
PC> declare variable color varchar(10);
PC> begin
PC> if (pParam=1) then color='red';
PC> else if (pParam=2) then color='yellow';
PC> selectionIf='You have selected '||:color||' bag';

PC> color=case :pParam when 1 then 'red' when 2 then 'yellow' end;
PC> selectionCase='You have selected '||:color||' bag';
PC> suspend;
PC> end
PC> ^
PC> set term ;^

PC> select * from tmp_sp(1);

PC> SELECTIONIF SELECTIONCASE
PC> =========================== ============================
PC> You have selected red bag You have selected red bag

PC> drop procedure tmp_sp;
PC> commit;

PC> ---

PC> Padding with spaces is not a bug! Spaces are there because string
PC> literals are CHARs, NOT VARCHARs. This is required by SQL standard.

PC> Relevant except from SQL standard:

PC> 5 Lexical elements

PC> 5.3 <literal>
PC> Syntax Rules
PC> ...
PC> 15) The declared type of a <character string literal> is fixed-length
PC> character string. The length of a <character string literal> is the
PC> number of <character representation>s that it contains.

PC> ...

PC> 6 Scalar expressions

PC> 6.11 <case expression>
PC> Syntax Rules
PC> ...
PC> 7) The declared type of a <case specification> is determined by applying
PC> Subclause 9.3, ‘‘Data types of results of aggregations’’, to the declared
PC> types of all <result expression>s in the <case specification>.


PC> 9 Additional common rules

PC> 9.3 Data types of results of aggregations
PC> Syntax Rules
PC> ...
PC> 3) Case:
PC> a) If any of the data types in DTS is character string, then:
PC> ...
PC> iii) Case:
PC> 1) If any of the data types in DTS is character large object string,
PC> then the result data type is character large object string with
PC> maximum length in characters equal to the maximum of the lengths in
PC> characters and maximum lengths in characters of the data types in DTS.

PC> 2) If any of the data types in DTS is variable-length character string,
PC> then the result data type is variable-length character string with
PC> maximum length in characters equal to the maximum of the lengths in
PC> characters and maximum lengths in characters of the data types in DTS.

PC> 3) Otherwise, the result data type is fixed-length character string with
PC> length in characters equal to the maximum of the lengths in characters
PC> of the data types in DTS.

PC> ----

PC> To sum it up, standard dictates that literals are CHARs, aggregated
PC> values has length of longest one and because CHARs are padded with
PC> spaces to declared length, we have such stupid output in CASE. Sure, it
PC> could be easily "fixed" with CAST or TRIM, but it's extremely annoying
PC> to do so. And if there is any real world case when CHAR is the right
PC> type for literals and VARCHAR the wrong one, I can't see it and would be
PC> glad to be enlightened by someone else.

PC> You may ask why I'm raising this issue here when Firebird's policy is to
PC> follow SQL standard whenever possible (even with stupid requirements),
PC> so annoying or not, we have to live with it. BUT... other databases are
PC> not so strict here, break the stupid standard requirement and use
PC> VARCHAR instead CHAR, for example:

PC> MS SQLServer 2012:

PC> SELECT 'a'+case 1 when 1 then '1 ' when 2 then '22222222222' end+'b'
PC> FROM [SCM].[dbo].[SERVERID]
PC> ----
PC> a1 b
PC> (1 row(s) affected)


PC> mySQL 5.6:

PC> select concat('a', case 1 when 1 then '1 ' when 2 then '22222222222'
PC> end, 'b') from tmp;
PC> | concat('a', case 1 when 1 then '1 ' when 2 then '22222222222' end, 'b') |
PC> |-------------------------------------------------------------------|
PC> | a1 b |


PC> oracle (not sure which version, provided by sqlZoo.net):

PC> SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
PC> FROM world
PC> 'A'||CASE1WHE..
PC> a1 b
PC> ...


PC> PostgreSQL (not sure which version, provided by sqlZoo.net):

PC> select concat('a', case 1 when 1 then '1 ' when 2 then '22222222222'
PC> end, 'b') from world
PC> concat
PC> a1 b
PC> ...


PC> db2 (not sure which version, provided by sqlZoo.net):

PC> SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
PC> FROM world
PC> 1
PC> a1 b
PC> ...


PC> So Firebird stands out from the flock here with:

PC> SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
PC> FROM rdb$database;
PC> CONCATENATION
PC> =============
PC> a1 b

PC> ---

PC> So Firebird behavior is even more annoying when you (have to or was used
PC> to) work with other databases.

PC> My question is: Could we sacrifice the standard compliance a little bit
PC> by using VARCHAR instead CHAR (length rules remain the same!) as others
PC> do? Because following the standard here really doesn't work in our favor
PC> in this particular case.

PC> My personal vote is for relaxing the rules and use VARCHAR. What is your
PC> opinion?

PC> best regards
PC> Pavel Cisar
PC> IBPhoenix
Jim Starkey
2016-01-05 15:30:06 UTC
Permalink
Hallelujah, Carlos!

At MySQL, I argued for SQL compliance until I was blue in the face but
without noticeable effect.

Database systems should have strings. Period. Not fixed strings,
variable strings, or bounded strings. String comparisons should be
blank extended. Nobody should ever have to worry about the semantic
differences between char and vchar.

Numbers should be numbers, too, but that's a different rant.

Netfrastructure, NuoDB, and Amorphous all have just "string." Unbounded
and simple. Falcon did too, but it couldn't be exposed.
Post by Carlos H. Cantu
I start wondering if nowadays, saying that a RDBMS "complies to the SQL
Standard" is seem by the users as a "plus".
Most of the time, I saw this as a good way to say: "Ok, Firebird is
Standard compliant, so you can move easily from another RDBMS to it".
But seems that all the others RDBMS don't care much about following
the SQL Standard, so I wonder if trying to follow it is of any good
nowadays.
Regarding your suggestion, I would vote for using VARCHAR too.
[]s
Carlos
http://www.firebirdnews.org
FireBase - http://www.FireBase.com.br
PC> Hi all,
PC> We have an annoying little problem. The visible manifestation is that
PC> literals in CASE expressions could be padded with spaces.
PC> set term ^;
PC> create procedure tmp_sp(pParam integer)
PC> returns (selectionIf varchar(40), selectionCase varchar(40))
PC> as
PC> declare variable color varchar(10);
PC> begin
PC> if (pParam=1) then color='red';
PC> else if (pParam=2) then color='yellow';
PC> selectionIf='You have selected '||:color||' bag';
PC> color=case :pParam when 1 then 'red' when 2 then 'yellow' end;
PC> selectionCase='You have selected '||:color||' bag';
PC> suspend;
PC> end
PC> ^
PC> set term ;^
PC> select * from tmp_sp(1);
PC> SELECTIONIF SELECTIONCASE
PC> =========================== ============================
PC> You have selected red bag You have selected red bag
PC> drop procedure tmp_sp;
PC> commit;
PC> ---
PC> Padding with spaces is not a bug! Spaces are there because string
PC> literals are CHARs, NOT VARCHARs. This is required by SQL standard.
PC> 5 Lexical elements
PC> 5.3 <literal>
PC> Syntax Rules
PC> ...
PC> 15) The declared type of a <character string literal> is fixed-length
PC> character string. The length of a <character string literal> is the
PC> number of <character representation>s that it contains.
PC> ...
PC> 6 Scalar expressions
PC> 6.11 <case expression>
PC> Syntax Rules
PC> ...
PC> 7) The declared type of a <case specification> is determined by applying
PC> Subclause 9.3, ‘‘Data types of results of aggregations’’, to the declared
PC> types of all <result expression>s in the <case specification>.
PC> 9 Additional common rules
PC> 9.3 Data types of results of aggregations
PC> Syntax Rules
PC> ...
PC> ...
PC> 1) If any of the data types in DTS is character large object string,
PC> then the result data type is character large object string with
PC> maximum length in characters equal to the maximum of the lengths in
PC> characters and maximum lengths in characters of the data types in DTS.
PC> 2) If any of the data types in DTS is variable-length character string,
PC> then the result data type is variable-length character string with
PC> maximum length in characters equal to the maximum of the lengths in
PC> characters and maximum lengths in characters of the data types in DTS.
PC> 3) Otherwise, the result data type is fixed-length character string with
PC> length in characters equal to the maximum of the lengths in characters
PC> of the data types in DTS.
PC> ----
PC> To sum it up, standard dictates that literals are CHARs, aggregated
PC> values has length of longest one and because CHARs are padded with
PC> spaces to declared length, we have such stupid output in CASE. Sure, it
PC> could be easily "fixed" with CAST or TRIM, but it's extremely annoying
PC> to do so. And if there is any real world case when CHAR is the right
PC> type for literals and VARCHAR the wrong one, I can't see it and would be
PC> glad to be enlightened by someone else.
PC> You may ask why I'm raising this issue here when Firebird's policy is to
PC> follow SQL standard whenever possible (even with stupid requirements),
PC> so annoying or not, we have to live with it. BUT... other databases are
PC> not so strict here, break the stupid standard requirement and use
PC> SELECT 'a'+case 1 when 1 then '1 ' when 2 then '22222222222' end+'b'
PC> FROM [SCM].[dbo].[SERVERID]
PC> ----
PC> a1 b
PC> (1 row(s) affected)
PC> select concat('a', case 1 when 1 then '1 ' when 2 then '22222222222'
PC> end, 'b') from tmp;
PC> | concat('a', case 1 when 1 then '1 ' when 2 then '22222222222' end, 'b') |
PC> |-------------------------------------------------------------------|
PC> | a1 b |
PC> SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
PC> FROM world
PC> 'A'||CASE1WHE..
PC> a1 b
PC> ...
PC> select concat('a', case 1 when 1 then '1 ' when 2 then '22222222222'
PC> end, 'b') from world
PC> concat
PC> a1 b
PC> ...
PC> SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
PC> FROM world
PC> 1
PC> a1 b
PC> ...
PC> SELECT 'a'||case 1 when 1 then '1 ' when 2 then '22222222222' end||'b'
PC> FROM rdb$database;
PC> CONCATENATION
PC> =============
PC> a1 b
PC> ---
PC> So Firebird behavior is even more annoying when you (have to or was used
PC> to) work with other databases.
PC> My question is: Could we sacrifice the standard compliance a little bit
PC> by using VARCHAR instead CHAR (length rules remain the same!) as others
PC> do? Because following the standard here really doesn't work in our favor
PC> in this particular case.
PC> My personal vote is for relaxing the rules and use VARCHAR. What is your
PC> opinion?
PC> best regards
PC> Pavel Cisar
PC> IBPhoenix
------------------------------------------------------------------------------
Firebird-Devel mailing list, web interface at https://lists.sourceforge.net/lists/listinfo/firebird-devel
Dmitry Yemanov
2016-01-05 14:37:28 UTC
Permalink
Post by Pavel Cisar
We have an annoying little problem.
We have it for the past decade, so I agree with describing this problem
as a "little" one ;-)
Post by Pavel Cisar
To sum it up, standard dictates that literals are CHARs, aggregated
values has length of longest one and because CHARs are padded with
spaces to declared length, we have such stupid output in CASE. Sure, it
could be easily "fixed" with CAST or TRIM, but it's extremely annoying
to do so. And if there is any real world case when CHAR is the right
type for literals and VARCHAR the wrong one, I can't see it and would be
glad to be enlightened by someone else.
First of all, let's distinguish between two things: (1) how string
literals are described and (2) how CASE evaluates the resulting
datatype. Changing any of them may lead to the desired result.
Post by Pavel Cisar
You may ask why I'm raising this issue here when Firebird's policy is to
follow SQL standard whenever possible (even with stupid requirements),
so annoying or not, we have to live with it.
We already have some differences against the standard, e.g. we always
evaluate concatenation as VARCHAR, even if both arguments are CHARs. We
can have more if we consider it feasible.
These examples say nothing about the approach used there: either
literals are VARCHARs, or CASE derives the datatype differenly, or both.

And I suppose Firebird is not really alone, see for MariaDB:

CASE ... THEN 'a' ... THEN 'abcd' ... ELSE 'abc' END

will return a result with a <data type> of CHAR(4), because <character
string literal>s are fixed-length character strings and the size of the
largest aggregated <literal> is 4 characters.
Post by Pavel Cisar
My question is: Could we sacrifice the standard compliance a little bit
by using VARCHAR instead CHAR (length rules remain the same!) as others
do? Because following the standard here really doesn't work in our favor
in this particular case.
I agree that such a CASE result is unexpected and may be considered
stupid. But I'm not convinced (yet) that CHAR->VARCHAR change for string
literals is a proper solution. It may introduce compatibility issues, so
we cannot touch it before v4. As a first attempt, I'd rather find some
way to return the expected result from CASE, e.g. implicitly cast all
CHAR arguments to VARCHAR before processing and thus return VARCHAR.


Dmitry
Wols Lists
2016-01-05 15:06:35 UTC
Permalink
Post by Dmitry Yemanov
These examples say nothing about the approach used there: either
literals are VARCHARs, or CASE derives the datatype differenly, or both.
CASE ... THEN 'a' ... THEN 'abcd' ... ELSE 'abc' END
will return a result with a <data type> of CHAR(4), because <character
string literal>s are fixed-length character strings and the size of the
largest aggregated <literal> is 4 characters.
But if you pass in a CHAR(3), surely you should get a CHAR(3) back?
Otherwise, your literal isn't really a literal because its datatype has
been changed?

Okay, I know sanity often doesn't enter into it when defining
specifications, but requiring all literals to be forced to the same
datatype does seem to be a fairly insane example :-)

(And as I read the spec, if CASE has a varchar in it somewhere, it can
return a varchar, so why not always return a varchar. Especially if,
again as I read it, if you mix char and varchar you will actually get
the desired result.)

So if we're changing the datatype anyway, we might as well change it to
varchar.

Cheers,
Wol
Leyne, Sean
2016-01-05 21:49:10 UTC
Permalink
Dmitry,
Post by Pavel Cisar
To sum it up, standard dictates that literals are CHARs, aggregated
values has length of longest one and because CHARs are padded with
spaces to declared length, we have such stupid output in CASE. Sure,
it could be easily "fixed" with CAST or TRIM, but it's extremely
annoying to do so. And if there is any real world case when CHAR is
the right type for literals and VARCHAR the wrong one, I can't see it
and would be glad to be enlightened by someone else.
First of all, let's distinguish between two things: (1) how string literals are
described and (2) how CASE evaluates the resulting datatype. Changing any
of them may lead to the desired result.
The issue is not the intermediate datatype but the final datatype.

In Pavel's use case "color" is a VarChar as such any value/string/variable which is assigned to it should be cast as a VarChar, regardless of the intermediate datatype.

The current outcome is wrong!


Sean

P.S. The fact that a fix for this could introduce compatibility issues is not a something we should care about when fixing invalid/wrong functionality. Compatibility issues are items which developers need to resolve for themselves, nothing is forcing a developer to adopt v3.
Arno Brinkman
2016-01-06 00:03:19 UTC
Permalink
Post by Leyne, Sean
P.S. The fact that a fix for this could introduce compatibility issues is
not a something we should care about when fixing invalid/wrong
functionality. Compatibility issues are items which developers need to
resolve for themselves, nothing is forcing a developer to adopt v3.
Well..... this :

SELECT 1 / 3 FROM RDB$DATABASE
SELECT 1.0 / 3 FROM RDB$DATABASE

should return 0.33333333333333333333333, agree ?

Exactly same, but then with numbers

DIALECT 5 ? :-p


Kind Regards,
Arno Brinkman
Dimitry Sibiryakov
2016-01-06 10:37:28 UTC
Permalink
Post by Arno Brinkman
SELECT 1 / 3 FROM RDB$DATABASE
SELECT 1.0 / 3 FROM RDB$DATABASE
should return 0.33333333333333333333333, agree ?
Actually, I agree. I believe that division should produce double precision result.
Post by Arno Brinkman
changing the math that is clearly described in the standard to something else is plain
wrong.

According to a quote from standard that was discussed a couple of months ago, it is not
described clearly, but left as "implementation-dependent".
--
WBR, SD.
Dmitry Yemanov
2016-01-06 07:42:04 UTC
Permalink
Post by Leyne, Sean
First of all, let's distinguish between two things: (1) how string literals are
described and (2) how CASE evaluates the resulting datatype. Changing any
of them may lead to the desired result.
The issue is not the intermediate datatype but the final datatype.
The final datatype of the CASE expression. And it can be altered without
describing literals as VARCHARs, that was the point.
Post by Leyne, Sean
In Pavel's use case "color" is a VarChar as such any value/string/variable which is assigned to it should be cast as a VarChar, regardless of the intermediate datatype.
The current outcome is wrong!
The SQL committee respectfully disagrees.
Post by Leyne, Sean
P.S. The fact that a fix for this could introduce compatibility issues is not a something we should care about when fixing invalid/wrong functionality.
Suggestion to describe literals as VARCHARs may fix the CASE issue but
break something else that used to work correctly. Do you care?


Dmitry
Leyne, Sean
2016-01-06 17:08:12 UTC
Permalink
Dmitry,
Post by Leyne, Sean
Post by Leyne, Sean
In Pavel's use case "color" is a VarChar as such any value/string/variable
which is assigned to it should be cast as a VarChar, regardless of the
intermediate datatype.
Post by Leyne, Sean
The current outcome is wrong!
The SQL committee respectfully disagrees.
Actually, given that MS SQL, Oracle, DB2 and Postgres all generate the results that Pavel and I expect, I would say that it is our interpretation of the standard which is wrong.
Post by Leyne, Sean
Suggestion to describe literals as VARCHARs may fix the CASE issue but break
something else that used to work correctly. Do you care?
Any change that we make can break something, that is always a possibility.

It is the developers responsibility to test their application when they are looking to adopt any new version of anything (tool, database, components...).
Adriano dos Santos Fernandes
2016-01-05 15:05:19 UTC
Permalink
Post by Pavel Cisar
Hi all,
We have an annoying little problem. The visible manifestation is that
literals in CASE expressions could be padded with spaces.
We also have DECODE. Let's see it:

SQL> select 'a' || decode(1, 1, 'a', 2, 'bbbbb') || 'c' from rdb$database;

CONCATENATION
=============
aac

It doesn't follow the CASE way, although at least in the README, it's
not documented.

But let's see it details:

SQL> set sqlda_display on;
SQL> select decode(1, 1, 'a', 2, 'bbbbb') from rdb$database;

INPUT message field count: 0

OUTPUT message field count: 1
01: sqltype: 452 TEXT Nullable scale: 0 subtype: 0 len: 5 charset: 0 NONE
: name: DECODE alias: DECODE
: table: owner:

DECODE
======
a

What? It returns CHAR!

The difference between the DECODE and CASE is that CASE adds an explicit
CAST to CHAR, while DECODE doesn't.

So DECODE returns the original expressions and when you concatenate it
with something, the expression is not padded.

That's weird. I'd say we need to change DECODE to be described as
VARCHAR in this case.

DECODE doesn't fulfill all CASE types, but it's easy to use and may
maintain the "expected" behavior.

PS: After all this, something me say that my original intention has to
do DECODE different than CASE but people didn't agreed and want DECODE
as CASE. So I tested with 2.5 too (above is 3.0) and DECODE works as
CASE. So we have some work to do in a way or another. :)


Adriano
Mark Rotteveel
2016-01-06 07:28:53 UTC
Permalink
No, please no. I can find some logic in changing the concatenation behavior as described (as I think that the standard might offer some leeway there, although I need to study on it first), but changing the math that is clearly described in the standard to something else is plain wrong.
Mark

----- Reply message -----
Van: "Arno Brinkman" <***@abvisie.nl>
Aan: "For discussion among Firebird Developers" <firebird-***@lists.sourceforge.net>
Onderwerp: [Firebird-devel] Literals in CASE expression
Datum: wo, jan. 6, 2016 01:03
Post by Leyne, Sean
P.S. The fact that a fix for this could introduce compatibility issues is
not a something we should care about when fixing invalid/wrong
functionality. Compatibility issues are items which developers need to
resolve for themselves, nothing is forcing a developer to adopt v3.
Well..... this :

SELECT 1 / 3 FROM RDB$DATABASE
SELECT 1.0 / 3 FROM RDB$DATABASE

should return 0.33333333333333333333333, agree ?

Exactly same, but then with numbers

DIALECT 5 ? :-p


Kind Regards,
Arno Brinkman
Dmitry Yemanov
2016-01-06 07:37:45 UTC
Permalink
Post by Mark Rotteveel
No, please no.
I believe Arno was writing with the sarcasm mode turned on ;-)


Dmitry
Mark Rotteveel
2016-01-06 07:42:06 UTC
Permalink
My sarcasm detector is not so good.
Mark

----- Reply message -----
Van: "Dmitry Yemanov" <***@yandex.ru>
Aan: "For discussion among Firebird Developers" <firebird-***@lists.sourceforge.net>
Onderwerp: [Firebird-devel] Literals in CASE expression
Datum: wo, jan. 6, 2016 08:37
Post by Mark Rotteveel
No, please no.
I believe Arno was writing with the sarcasm mode turned on ;-)


Dmitry
Mark Rotteveel
2016-01-06 10:58:26 UTC
Permalink
No the scale is implementation dependent with numeric division, however there is no doubt that in this case it should be handled as integer division.
Mark

----- Reply message -----
Van: "Dimitry Sibiryakov" <***@ibphoenix.com>
Aan: "For discussion among Firebird Developers" <firebird-***@lists.sourceforge.net>
Onderwerp: [Firebird-devel] Literals in CASE expression
Datum: wo, jan. 6, 2016 11:37
Post by Arno Brinkman
SELECT 1 / 3 FROM RDB$DATABASE
SELECT 1.0 / 3 FROM RDB$DATABASE
should return 0.33333333333333333333333, agree ?
Actually, I agree. I believe that division should produce double precision result.
Post by Arno Brinkman
changing the math that is clearly described in the standard to something else is plain
wrong.

According to a quote from standard that was discussed a couple of months ago, it is not
described clearly, but left as "implementation-dependent".
--
WBR, SD.
Continue reading on narkive:
Loading...