UNION ALL Data Migration
Data migration considerations for UNION ALL.
UNION ALL is a SQL operator that allows the combination of multiple resultsets. The syntax is the following:
query_expression_1 UNION [ ALL ] query_expression_2For more information, please review the following Teradata documentation.
Column Size differences
Even though the operator is translated into the same operator in Snowflake, there could be detailed differences in functional equivalence. For example, the union of different columns which have different column sizes. Teradata does truncate the values when the first SELECT statement contains less space in the columns.
Teradata behavior
For this example, the following input will show the Teradata behavior.
CREATE TABLE table1
(
col1 VARCHAR(20)
);
INSERT INTO table1 VALUES('value 1 abcdefghijk');
INSERT INTO table1 VALUES('value 2 abcdefghijk');
CREATE TABLE table2
(
col1 VARCHAR(10)
);
INSERT INTO table2 VALUES('t2 row 1 a');
INSERT INTO table2 VALUES('t2 row 2 a');
INSERT INTO table2 VALUES('t2 row 3 a');CREATE OR REPLACE TABLE table1
(
col1 VARCHAR(20)
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "teradata", "convertedOn": "10/14/2024" }}'
;
INSERT INTO table1
VALUES ('value 1 abcdefghijk');
INSERT INTO table1
VALUES ('value 2 abcdefghijk');
CREATE OR REPLACE TABLE table2
(
col1 VARCHAR(10)
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "teradata", "convertedOn": "10/14/2024" }}'
;
INSERT INTO table2
VALUES ('t2 row 1 a');
INSERT INTO table2
VALUES ('t2 row 2 a');
INSERT INTO table2
VALUES ('t2 row 3 a');Case 1 - one single column: UNION ALL for a column varchar (20) over a column varchar (10)
For this case, the functional equivalence is the same
Case 2 - one single column: UNION ALL for a column varchar (10) over a column varchar (20)
In this case, the function equivalence is not the same.
The following case does not show functional equivalence in Snowflake. The column values should be truncated as in the Teradata sample.
Workaround to get the same functionality
In this case, the size of the column of the table2 is 10 and the table1 is 20. So, the size of the first column in the query should be the element to complete the LEFT() function used here. Review more information about the Snowflake LEFT function HERE.
Case 3 - multiple columns - same size by table: UNION ALL for columns varchar (20) over columns varchar (10)
For this case, it is required to set up new data as follows:
Once the new tables and data are created, the following query can be evaluated.
value 1 abcdefghijk
value 1 abcdefghijk
t2 row 3 a
t2 row 3 b
value 2 abcdefghijk
value 2 abcdefghijk
t2 row 1 a
t2 row 1 b
t2 row 2 a
t2 row 2 b
value 1 abcdefghijk
value 1 abcdefghijk
value 2 abcdefghijk
value 2 abcdefghijk
t2 row 1 a
t2 row 1 b
t2 row 2 a
t2 row 2 b
t2 row 3 a
t2 row 3 b
Case 4 - multiple columns - same size by table: UNION ALL for columns varchar (10) over columns varchar (20)
In this case, the function equivalence is not the same.
t2 row 3 a
t2 row 3 b
value 1 ab
value 1 ab
t2 row 1 a
t2 row 1 b
t2 row 2 a
t2 row 2 b
value 2 ab
value 2 ab
t2 row 1 a
t2 row 1 b
t2 row 2 a
t2 row 2 b
t2 row 3 a
t2 row 3 b
value 1 abcdefghijk
value 1 abcdefghijk
value 2 abcdefghijk
value 2 abcdefghijk
Workaround to get the same functionality
Apply the column size to the second SELECT on the columns to get the same functionality.
t2 row 1 a
t2 row 1 b
t2 row 2 a
t2 row 2 b
t2 row 3 a
t2 row 3 b
value 1 ab
value 1 ab
value 2 ab
value 2 ab
Case 5 - multiple columns - different sizes by table: UNION ALL for columns varchar (10) over columns varchar (20)
For this case, it is required to set up new data as follows:
Once the new tables and data are created, the following query can be evaluated.
value 1 abcdefghijk
value 1 abcd
t2 row 3 a
t2 3b
value 2 abcdefghijk
value 2 abcd
t2 row 1 a
t2 1b
t2 row 2 a
t2 2b
value 1 abcdefghijk
value 1 abcd
value 2 abcdefghijk
value 2 abcd
t2 row 1 a
t2 1b
t2 row 2 a
t2 2b
t2 row 3 a
t2 3b
Case 6 - multiple columns - different sizes by table: UNION ALL for columns varchar (20), varchar(10) over columns varchar (10), varchar(5)
In this case, the function equivalence is not the same.
t2 row 3 a
t2 3b
value 1 ab
value
t2 row 1 a
t2 1b
t2 row 2 a
t2 2b
value 2 ab
value
t2 row 1 a
t2 1b
t2 row 2 a
t2 2b
t2 row 3 a
t2 3b
value 1 abcdefghijk
value 1 abcd
value 2 abcdefghijk
value 2 abcd
Workaround to get the same functionality
The column with the smallest size from the first SELECT is used to determine the size of the columns from the second SELECT.
t2 row 3 a
t2 3b
value 1 ab
value
t2 row 1 a
t2 1b
t2 row 2 a
t2 2b
value 2 ab
value
Case 7 - multiple columns expression - different sizes by table: UNION ALL for columns varchar (20), varchar(20) over columns varchar (10), varchar(10)
Use the data set up here. Once the new tables and data are created, the following query can be evaluated.
value 1 abcdefghijkvalue 1 abcdefghijk
t2 row 3 at2 row 3 b
value 2 abcdefghijkvalue 2 abcdefghijk
t2 row 1 at2 row 1 b
t2 row 2 at2 row 2 b
value 1 abcdefghijkvalue 1 abcdefghijk
value 2 abcdefghijkvalue 2 abcdefghijk
t2 row 1 at2 row 1 b
t2 row 2 at2 row 2 b
t2 row 3 at2 row 3 b
Case 8 - multiple columns expression - different sizes by table: UNION ALL for columns varchar (20), varchar(20) over columns varchar (10), varchar(10)
This case has functional differences.
t2 row 1 at2 row 1 b
t2 row 2 at2 row 2 b
t2 row 3 at2 row 3 b
value 1 abcdefghijkv
value 2 abcdefghijkv
t2 row 1 at2 row 1 b
t2 row 2 at2 row 2 b
t2 row 3 at2 row 3 b
value 1 abcdefghijkvalue 1 abcdefghijk
value 2 abcdefghijkvalue 2 abcdefghijk
Workaround to get the same functionality
The sum of the column sizes of the less big column should be used in the LEFT function. For example, the less big column is varchar(10), so the limit of the LEFT function should be 20 (10 + 10).
The sum of the first SELECT if this is less big, it would be used for the truncation of the values.
t2 row 1 at2 row 1 b
t2 row 2 at2 row 2 b
t2 row 3 at2 row 3 b
value 1 abcdefghijkv
value 2 abcdefghijkv
Other considerations about column size differences
CHARandVARCHARbehave the same.Number columns may behave differently. The numbers cannot be truncated, so there is an overflow in the Teradata environment. So, this is not applied to these data types. Review the following example:
Last updated
