Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

decimals,test: Additional tests for the DECIMAL type #7650

Merged
merged 1 commit into from
Aug 2, 2021
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
112 changes: 112 additions & 0 deletions test/testdrive/decimal-distinct.td
Original file line number Diff line number Diff line change
@@ -0,0 +1,112 @@
# Copyright Materialize, Inc. and contributors. All rights reserved.
#
# Use of this software is governed by the Business Source License
# included in the LICENSE file at the root of this repository.
#
# As of the Change Date specified in that file, in accordance with
# the Business Source License, use of this software will be governed
# by the Apache License, Version 2.0.

#
# Test that decimal numbers that are the same are considered identical
# and those that are truly different are considered distinct
#

#
# Truly distinct numbers
#

> CREATE TABLE decimal_distinct (f1 DECIMAL);

> INSERT INTO decimal_distinct VALUES ('-999999999999999999999999999999999999999');

> INSERT INTO decimal_distinct VALUES ('-1.00000000000000000000000000000000000001');

> INSERT INTO decimal_distinct VALUES ('-0.999999999999999999999999999999999999999');

> INSERT INTO decimal_distinct VALUES ('-0.000000000000000000000000000000000000001');

> INSERT INTO decimal_distinct VALUES ('0.000000000000000000000000000000000000001');

> INSERT INTO decimal_distinct VALUES ('0.000000000000000000000000000000000000002');

> INSERT INTO decimal_distinct VALUES ('0.999999999999999999999999999999999999998');

> INSERT INTO decimal_distinct VALUES ('0.999999999999999999999999999999999999999');

> INSERT INTO decimal_distinct VALUES ('1.00000000000000000000000000000000000001');

> INSERT INTO decimal_distinct VALUES ('1.00000000000000000000000000000000000002');

> INSERT INTO decimal_distinct VALUES ('999999999999999999999999999999999999999');

> INSERT INTO decimal_distinct VALUES ('999999999999999999999999999999999999998');

> SELECT DISTINCT f1 FROM decimal_distinct;
-999999999999999999999999999999999999999
-1.00000000000000000000000000000000000001
-0.999999999999999999999999999999999999999
-0.000000000000000000000000000000000000001
0.000000000000000000000000000000000000001
0.000000000000000000000000000000000000002
0.999999999999999999999999999999999999998
0.999999999999999999999999999999999999999
1.00000000000000000000000000000000000001
1.00000000000000000000000000000000000002
999999999999999999999999999999999999998
999999999999999999999999999999999999999

> SELECT f1 FROM decimal_distinct UNION DISTINCT SELECT * FROM decimal_distinct;
-999999999999999999999999999999999999999
-1.00000000000000000000000000000000000001
-0.999999999999999999999999999999999999999
-0.000000000000000000000000000000000000001
0.000000000000000000000000000000000000001
0.000000000000000000000000000000000000002
0.999999999999999999999999999999999999998
0.999999999999999999999999999999999999999
1.00000000000000000000000000000000000001
1.00000000000000000000000000000000000002
999999999999999999999999999999999999998
999999999999999999999999999999999999999

> SELECT COUNT(DISTINCT f1), COUNT(*) FROM decimal_distinct;
12 12

> SELECT COUNT(DISTINCT f1::DECIMAL(5,2)) FROM decimal_distinct WHERE f1 BETWEEN -1 AND 1;
3

#
# Fundamentally "identical" numbers as far as the DECIMAL type is concerned
#

> CREATE TABLE decimal_same (f1 DECIMAL);

> INSERT INTO decimal_same VALUES (0),(-0);

# The numbers below differ only in the part that is outside of the precision of the DECIMAL type

> INSERT INTO decimal_same VALUES ('999999999999999999999999999999999999999.1');

> INSERT INTO decimal_same VALUES ('999999999999999999999999999999999999999.2');

# The number of leading or trailing zeroes should not matter

> INSERT INTO decimal_same VALUES ('1.010');

> INSERT INTO decimal_same VALUES ('1.01000');

> INSERT INTO decimal_same VALUES ('001.01');

> SELECT DISTINCT f1 FROM decimal_same;
0
1.01
999999999999999999999999999999999999999

> SELECT COUNT(DISTINCT f1) FROM decimal_same;
3

> SELECT f1 FROM decimal_same GROUP BY 1;
0
1.01
999999999999999999999999999999999999999
109 changes: 109 additions & 0 deletions test/testdrive/decimal-join.td
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
# Copyright Materialize, Inc. and contributors. All rights reserved.
#
# Use of this software is governed by the Business Source License
# included in the LICENSE file at the root of this repository.
#
# As of the Change Date specified in that file, in accordance with
# the Business Source License, use of this software will be governed
# by the Apache License, Version 2.0.

#
# Check that decimal columns can properly be joined
#

#
# Different scales, same precision
#

> CREATE TABLE d5_2 (f1 DECIMAL(5,2));

> INSERT INTO d5_2 VALUES (12.34);

> CREATE TABLE d6_2 (f1 DECIMAL(6,2));

> INSERT INTO d6_2 VALUES (12.34);

> SELECT * FROM d5_2 JOIN d6_2 ON (d5_2.f1 = d6_2.f1);
12.34 12.34

#
# Same scale, different precisions
#

> CREATE TABLE d5_3(f1 DECIMAL(5,3));

> INSERT INTO d5_3 VALUES (12.340);

> SELECT * FROM d5_2 JOIN d5_3 ON (d5_2.f1 = d5_3.f1);
12.34 12.34


#
# Use of CAST in the join condition
#

> CREATE TABLE d5_3a (f1 DECIMAL(5,3));

> INSERT INTO d5_3a VALUES (12.341);

# cast to reduce precision
> SELECT * FROM d5_2 JOIN d5_3a ON (d5_2.f1 = d5_3a.f1::DECIMAL(5,2));
12.34 12.341

> SELECT * FROM d5_2 JOIN d5_3a ON (d5_2.f1 = ROUND(d5_3a.f1,2));
12.34 12.341

# cast to increase precision
> SELECT * FROM d5_2 JOIN d5_3 ON (d5_2.f1::DECIMAL(5,4) = d5_3.f1);
12.34 12.34

#
# Join between string and decimal
#

> CREATE TABLE s (f1 STRING);

> INSERT INTO s VALUES ('012.34'), ('12.34'), ('12.340');

> SELECT * FROM d5_2 JOIN s ON (d5_2.f1 = s.f1::decimal);
12.34 012.34
12.34 12.34
12.34 12.340

#
# Join between integer and decimal
#

> CREATE TABLE d5_2b (f1 DECIMAL(5,2));

> INSERT INTO d5_2b VALUES (12);

> CREATE TABLE i (f1 INTEGER);

> INSERT INTO i VALUES (12);

> SELECT * FROM d5_2b JOIN i ON d5_2b.f1 = i.f1;
12 12


#
# Join between float and decimal
#

> CREATE TABLE f (f1 DOUBLE);

> INSERT INTO f VALUES (12.34);

> SELECT * FROM d5_2 JOIN f ON d5_2.f1 = f.f1
12.34 12.34

#
# Join using an arithmetic expression
#

> CREATE TABLE d5_2c (f1 DECIMAL(5,2));

> INSERT INTO d5_2c VALUES (123.4);

> SELECT * FROM d5_2 JOIN d5_2c ON (d5_2.f1 = d5_2c.f1 / 10);
12.34 123.4
133 changes: 133 additions & 0 deletions test/testdrive/decimal-order.td
Original file line number Diff line number Diff line change
@@ -0,0 +1,133 @@
# Copyright Materialize, Inc. and contributors. All rights reserved.
#
# Use of this software is governed by the Business Source License
# included in the LICENSE file at the root of this repository.
#
# As of the Change Date specified in that file, in accordance with
# the Business Source License, use of this software will be governed
# by the Apache License, Version 2.0.

#
# Make sure DECIMAL numbers are ordered appropriately in various contexts
#

#
# Simple comparisons
#

> SELECT '0.000000000000000000000000000000000000001'::decimal < '0.000000000000000000000000000000000000002'::decimal;
true

> SELECT '999999999999999999999999999999999999998'::decimal < '999999999999999999999999999999999999999'::decimal;
true

#
# Across types
#

> SELECT '0.000000000000000000000000000000000000001'::decimal < '0.000000000000000000000000000000000000002'::double;
true

# Due to loss of precision, this is unexpectedly false
> SELECT '999999999999999999999999999999999999998'::decimal < '999999999999999999999999999999999999999'::double;
false

> SELECT '0'::double = '-0'::decimal;
true

> SELECT '-0'::double = '0'::decimal;
true

#
# When used by a top-level ORDER BY
#
# Since testdrive sorts results by default, we use LIMIT + OFFSET to "probe" the correct placement of individual rows
#
#

> SELECT * FROM (VALUES ('999999999999999999999999999999999999998'::decimal), ('999999999999999999999999999999999999999')) AS t1 ORDER BY 1 LIMIT 1 OFFSET 0;
999999999999999999999999999999999999998

> SELECT * FROM (VALUES ('999999999999999999999999999999999999998'::decimal), ('999999999999999999999999999999999999999')) AS t1 ORDER BY 1 LIMIT 1 OFFSET 1;
999999999999999999999999999999999999999

> SELECT * FROM (VALUES ('0.0'::decimal), ('0.000000000000000000000000000000000000001'::decimal)) AS t1 ORDER BY 1 LIMIT 1 OFFSET 0;
0

> SELECT * FROM (VALUES ('0.0'::decimal), ('0.000000000000000000000000000000000000001'::decimal)) AS t1 ORDER BY 1 LIMIT 1 OFFSET 1;
0.000000000000000000000000000000000000001

> SELECT * FROM (VALUES ('0.000000000000000000000000000000000000001'::decimal), ('0.000000000000000000000000000000000000002'::decimal)) AS t1 ORDER BY 1 LIMIT 1 OFFSET 0;
0.000000000000000000000000000000000000001

> SELECT * FROM (VALUES ('0.000000000000000000000000000000000000001'::decimal), ('0.000000000000000000000000000000000000002'::decimal)) AS t1 ORDER BY 1 LIMIT 1 OFFSET 1;
0.000000000000000000000000000000000000002

# Negative zero is equal to positive zero, so the two are not ordered in any way against each other, the ordering of the second column applies

> SELECT * FROM (VALUES ('0'::decimal, 'row1'), ('-0', 'row2'), ('123', 'prevent optimizations')) AS t1 ORDER BY 1,2 LIMIT 1 OFFSET 0;
0 row1

> SELECT * FROM (VALUES ('0'::decimal, 'row1'), ('-0', 'row2'), ('123', 'prevent optimizations')) AS t1 ORDER BY 1,2 LIMIT 1 OFFSET 1;
0 row2

#

# Different trailing or leading zeroes should amount to the same thing, that is, the order is determined by the second column alone

> SELECT * FROM (VALUES ('0.10'::decimal, 'row1'), ('0.1', 'row2'), ('00.100', 'row3')) AS t1 ORDER BY 1,2 LIMIT 1 OFFSET 0;
0.1 row1

> SELECT * FROM (VALUES ('0.10'::decimal, 'row1'), ('0.1', 'row2'), ('00.100', 'row3')) AS t1 ORDER BY 1,2 LIMIT 1 OFFSET 1;
0.1 row2

> SELECT * FROM (VALUES ('0.10'::decimal, 'row1'), ('0.1', 'row2'), ('00.100', 'row3')) AS t1 ORDER BY 1,2 LIMIT 1 OFFSET 2;
0.1 row3

#
# When used by a TopK operator inside the dataflow
#

> SELECT MIN(column1 + 0) FROM (SELECT column1 + 0 AS column1 FROM (VALUES ('999999999999999999999999999999999999998'::decimal), ('999999999999999999999999999999999999999')) AS t1 ORDER BY 1 LIMIT 1 OFFSET 0);
999999999999999999999999999999999999998

> SELECT MIN(column1 + 0) FROM (SELECT column1 + 0 AS column1 FROM (VALUES ('999999999999999999999999999999999999998'::decimal), ('999999999999999999999999999999999999999')) AS t1 ORDER BY 1 LIMIT 1 OFFSET 1);
999999999999999999999999999999999999999


> SELECT column1 + 0, column2 FROM (
SELECT column1 + 0 AS column1 , column2 FROM (
SELECT '0.10'::decimal(3,2) AS column1, 'row1' AS column2 UNION ALL SELECT '0.1'::decimal(2,1), 'row2' UNION ALL SELECT '00.100'::decimal(5,3), 'row3' UNION ALL SELECT '123'::decimal, 'prevent optimizations'
) AS t1
ORDER BY 1,2 LIMIT 1 OFFSET 0
);
0.1 row1

> SELECT column1 + 0, column2 FROM (
SELECT column1 + 0 AS column1 , column2 FROM (
SELECT '0.10'::decimal(3,2) AS column1, 'row1' AS column2 UNION ALL SELECT '0.1'::decimal(2,1), 'row2' UNION ALL SELECT '00.100'::decimal(5,3), 'row3' UNION ALL SELECT '123'::decimal, 'prevent optimizations'
) AS t1
ORDER BY 1,2 LIMIT 1 OFFSET 1
);
0.1 row2

> SELECT column1 + 0, column2 FROM (
SELECT column1 + 0 AS column1 , column2 FROM (
SELECT '0.10'::decimal(3,2) AS column1, 'row1' AS column2 UNION ALL SELECT '0.1'::decimal(2,1), 'row2' UNION ALL SELECT '00.100'::decimal(5,3), 'row3' UNION ALL SELECT '123'::decimal, 'prevent optimizations'
) AS t1
ORDER BY 1,2 LIMIT 1 OFFSET 2
);
0.1 row3

#
# Infinity
#

# Positive Infinity is greater than largest decimal number

> SELECT (SELECT SUM(column1) FROM (VALUES ('999999999999999999999999999999999999999'::decimal), ('999999999999999999999999999999999999999'))) > '999999999999999999999999999999999999999'::decimal;
true

# Negative Infinity is smaller than the smallest number
> SELECT (SELECT SUM(column1) FROM (VALUES ('-999999999999999999999999999999999999999'::decimal), ('-999999999999999999999999999999999999999'))) < '-999999999999999999999999999999999999999'::decimal;
true
Loading