Last active
August 29, 2015 13:59
-
-
Save schnell18/10618255 to your computer and use it in GitHub Desktop.
Sample queries to demonstrate type affinity and type conversion in comparison expression
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
CREATE TABLE t1( | |
a TEXT, -- text affinity | |
b NUMERIC, -- numeric affinity | |
c BLOB, -- no affinity | |
d -- no affinity | |
); | |
-- Values will be stored as TEXT, INTEGER, TEXT, and INTEGER respectively | |
INSERT INTO t1 VALUES('500', '500', '500', 500); | |
SELECT typeof(a), typeof(b), typeof(c), typeof(d) FROM t1; | |
text|integer|text|integer | |
-- Because column "a" has text affinity, numeric values on the | |
-- right-hand side of the comparisons are converted to text before | |
-- the comparison occurs. | |
SELECT a < 40, a < 60, a < 600 FROM t1; | |
0|1|1 | |
-- Text affinity is applied to the right-hand operands but since | |
-- they are already TEXT this is a no-op; no conversions occur. | |
SELECT a < '40', a < '60', a < '600' FROM t1; | |
0|1|1 | |
-- Column "b" has numeric affinity and so numeric affinity is applied | |
-- to the operands on the right. Since the operands are already numeric, | |
-- the application of affinity is a no-op; no conversions occur. All | |
-- values are compared numerically. | |
SELECT b < 40, b < 60, b < 600 FROM t1; | |
0|0|1 | |
-- Numeric affinity is applied to operands on the right, converting them | |
-- from text to integers. Then a numeric comparison occurs. | |
SELECT b < '40', b < '60', b < '600' FROM t1; | |
0|0|1 | |
-- No affinity conversions occur. Right-hand side values all have | |
-- storage class INTEGER which are always less than the TEXT values | |
-- on the left. | |
SELECT c < 40, c < 60, c < 600 FROM t1; | |
0|0|0 | |
-- No affinity conversions occur. Values are compared as TEXT. | |
SELECT c < '40', c < '60', c < '600' FROM t1; | |
0|1|1 | |
-- No affinity conversions occur. Right-hand side values all have | |
-- storage class INTEGER which compare numerically with the INTEGER | |
-- values on the left. | |
SELECT d < 40, d < 60, d < 600 FROM t1; | |
0|0|1 | |
-- No affinity conversions occur. INTEGER values on the left are | |
-- always less than TEXT values on the right. | |
SELECT d < '40', d < '60', d < '600' FROM t1; | |
1|1|1 |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment