Re: [sqlite] Is this a bug with expression evaluation?
Tony Papadimitriou wrote: > I really don't know what the standard says, but here are two different > opinions in implementation. > > MySQL example: You know that the "SQL" in "MySQL" is actually the abbreviation of "something quite loose"? ;-) Anyway, it appears even MySQL conforms to SQL-92 subclause 6.12: | 1) If the data type of both operands of a dyadic arithmetic opera- |tor is exact numeric, then the data type of the result is exact |numeric, with precision and scale determined as follows: |[...] |d) The precision and scale of the result of division is | implementation-defined. Regards, Clemens ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
Re: [sqlite] Is this a bug with expression evaluation?
On 12/14/17, 12:08 PM, "sqlite-users on behalf of Simon Slavin" wrote: > Just to remind you that if something is not documented it can change. The > next version of SQLite might decide that 1 / 2 is 0. So don’t write code > that depends on it. I think it already does: sqlite> select 1/2; 0 sqlite> ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
Re: [sqlite] Is this a bug with expression evaluation?
On 12/14/17, Tony Papadimitriou wrote: > > MySQL example: > mysql> select 1/2; > ++ > | 1/2| > ++ > | 0.5000 | > ++ > 1 row in set (0.13 sec) MySQL is the only database engine that behaves this way. All others do integer arithmetic on integer values. This is probably the reason that MySQL has the separate "DIV" operator for integer division, whereas everybody else makes due with the standard "/" operator. -- D. Richard Hipp d...@sqlite.org ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
Re: [sqlite] Is this a bug with expression evaluation?
On 14 Dec 2017, at 5:03pm, Tony Papadimitriou wrote: > SQLite3 (https://sqlite.org/datatype3.html) -- "Otherwise, an expression has > no affinity. " > It seems that 'no affinity' gets translated to integer affinity, then. Just to remind you that if something is not documented it can change. The next version of SQLite might decide that 1 / 2 is 0. So don’t write code that depends on it. Simon. ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
Re: [sqlite] Is this a bug with expression evaluation?
-Original Message- From: J. King Someone please correct me if I'm wrong, but I believe it's mandated by the SQL standard that integer division is used when both operands are integers. I really don't know what the standard says, but here are two different opinions in implementation. MySQL example: mysql> select 1/2; ++ | 1/2| ++ | 0.5000 | ++ 1 row in set (0.13 sec) PostgreSQL example: psql=# select 1/2; ?column? -- 0 (1 row) Your synthetic example doesn't use a fixed table, but if it did the easiest solution for you would probably be to define any columns where you need arbitrary precision as REAL rather than INTEGER, and SQLite column >affinity would do the rest. SQLite3 (https://sqlite.org/datatype3.html) -- "Otherwise, an expression has no affinity. " It seems that 'no affinity' gets translated to integer affinity, then. Is there a way to default to float? ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
Re: [sqlite] Is this a bug with expression evaluation?
Someone please correct me if I'm wrong, but I believe it's mandated by the SQL standard that integer division is used when both operands are integers. Your synthetic example doesn't use a fixed table, but if it did the easiest solution for you would probably be to define any columns where you need arbitrary precision as REAL rather than INTEGER, and SQLite column affinity would do the rest. Otherwise, yes, I believe you would need to cast. On December 14, 2017 11:36:19 AM EST, Tony Papadimitriou wrote: >I’ve noticed this (very annoying) behavior: > >select column1*(24/100) wrong from (values(100)); > >Removing the parentheses yields the correct result: > >select column1*24/100 correct from (values(100)); > >This obviously behaves like integer math is used and (24/100) gets >truncated to zero. > >If I add a dot to either number (e.g., 24. or 100.) I get the correct >result. >But, with named fields, it’s not as easy as adding a dot: > >select column1*(column2/column3) wrong from (values(100,24,100)); >select column1*column2/column3 correct from (values(100,24,100)); > >So, to get correct answer I have to use a cast for either field? > >select column1*(cast(column2 as float)/column3) correct from >(values(100,24,100)); > >In this example removing the parentheses is a simple solution. >But if the expression was column1*(1+column2/column3) a cast is the >only way? (Hope not!) > >Anyway, if all this happens to be so by design, is there at least some >way to default to float math rather than integer? > >Thanks. >___ >sqlite-users mailing list >sqlite-users@mailinglists.sqlite.org >http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users -- Sent from my Android device with K-9 Mail. Please excuse my brevity. ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
Re: [sqlite] Is this a bug with expression evaluation?
I just multiply by 1.0 Select column1*(column2 * 1.0 / column3)... Removing the parentheses only provide the correct results in your example. It's still using integer math, it's just performing the multiply first, as per order of operations. -Original Message- From: sqlite-users [mailto:sqlite-users-boun...@mailinglists.sqlite.org] On Behalf Of Tony Papadimitriou Sent: Thursday, December 14, 2017 11:36 AM To: sqlite-users@mailinglists.sqlite.org Subject: [sqlite] Is this a bug with expression evaluation? I’ve noticed this (very annoying) behavior: select column1*(24/100) wrong from (values(100)); Removing the parentheses yields the correct result: select column1*24/100 correct from (values(100)); This obviously behaves like integer math is used and (24/100) gets truncated to zero. If I add a dot to either number (e.g., 24. or 100.) I get the correct result. But, with named fields, it’s not as easy as adding a dot: select column1*(column2/column3) wrong from (values(100,24,100)); select column1*column2/column3 correct from (values(100,24,100)); So, to get correct answer I have to use a cast for either field? select column1*(cast(column2 as float)/column3) correct from (values(100,24,100)); In this example removing the parentheses is a simple solution. But if the expression was column1*(1+column2/column3) a cast is the only way? (Hope not!) Anyway, if all this happens to be so by design, is there at least some way to default to float math rather than integer? Thanks. ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users Confidentiality notice: This e-mail is intended solely for use of the individual or entity to which it is addressed and may contain information that is proprietary, privileged, company confidential and/or exempt from disclosure under applicable law. If the reader is not the intended recipient or agent responsible for delivering the message to the intended recipient, you are hereby notified that any dissemination, distribution or copying of this communication is strictly prohibited. If you have received this communication in error, please notify the sender by reply e-mail or collect telephone call and delete or destroy all copies of this e-mail message, any physical copies made of this e-mail message and/or any file attachment(s). ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users
[sqlite] Is this a bug with expression evaluation?
I’ve noticed this (very annoying) behavior: select column1*(24/100) wrong from (values(100)); Removing the parentheses yields the correct result: select column1*24/100 correct from (values(100)); This obviously behaves like integer math is used and (24/100) gets truncated to zero. If I add a dot to either number (e.g., 24. or 100.) I get the correct result. But, with named fields, it’s not as easy as adding a dot: select column1*(column2/column3) wrong from (values(100,24,100)); select column1*column2/column3 correct from (values(100,24,100)); So, to get correct answer I have to use a cast for either field? select column1*(cast(column2 as float)/column3) correct from (values(100,24,100)); In this example removing the parentheses is a simple solution. But if the expression was column1*(1+column2/column3) a cast is the only way? (Hope not!) Anyway, if all this happens to be so by design, is there at least some way to default to float math rather than integer? Thanks. ___ sqlite-users mailing list sqlite-users@mailinglists.sqlite.org http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users