SnowConvert AI - Redshift - Built-in functions¶
Note
For more information about built-in functions and their Snowflake equivalents, also see Common built-in functions.
Aggregate Functions¶
Aggregate functions compute a single result value from a set of input values. (Redshift SQL Language Reference Aggregate Functions).
Redshift |
Snowflake |
---|---|
ANY_VALUE ( [ DISTINCT |
ALL ] expression ) |
AVG ( [ DISTINCT | ALL ] expression ) |
AVG ( [ DISTINCT ] expression) Notes: Redshift and Snowflake may show different precision/decimals due to data type rounding/formatting. |
Notes: Redshift’s DISTINCT ignores trailing spaces (‘a ‘ = ‘a’); Snowflake’s does not. (See SSC-FDM-PG0013). |
|
Notes: Snowflake does not allow the use of date types, while Redshift does. (See SSC-FDM-PG0013). |
|
STDDEV/STDDEV_SAMP ( [ DISTINCT |
ALL ] expression) STDDEV_POP ( [ DISTINCT |
VARIANCE/VAR_SAMP ( [ DISTINCT |
ALL ] expression) VAR_POP ( [ DISTINCT |
Array Functions¶
Creates an array of the SUPER data type. (Redshift SQL Language Reference Array Functions).
Redshift |
Snowflake |
---|---|
ARRAY ( [ expr1 ] [ , expr2 [ , … ] ] ) |
( [ <expr1> ] [ , <expr2> [ , … ] ] ) |
ARRAY_CONCAT ( super_expr1, super_expr2 ) |
ARRAY_CAT ( <array1> , <array2> ) |
( super_expr1,super_expr2,.. ) |
ARRAY_FLATTEN ( <array> ) Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
GET_ARRAY_LENGTH ( super_expr ) |
ARRAY_SIZE ( <array> | <variant>) |
SPLIT_TO_ARRAY ( string,delimiter ) |
SPLIT (<string>, <separator>) Notes: Redshift allows missing delimiters; Snowflake requires them, defaulting to comma |
SUBARRAY ( super_expr, start_position, length ) |
ARRAY_SLICE ( <array> , <from> , <to> ) Notes: Function names and the second argument differ; adjust arguments for equivalence. |
Conditional expressions¶
Redshift |
Snowflake |
---|---|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
COALESCE ( expression, expression, … ) |
COALESCE ( expression, expression, … ) |
GREATEST ( value [, …] ) |
GREATEST_IGNORE_NULLS ( <expr1> [, <expr2> … ] ) |
LEAST ( value [, …] ) |
LEAST_IGNORE_NULLS ( <expr1> [, <expr2> … ]) |
NVL( expression, expression, … ) |
NVL ( expression, expression ) Notes: Redshift’s NVL accepts multiple arguments; Snowflake’s NVL accepts only two. To match Redshift behavior, NVL with more than two arguments is converted to COALESCE. |
Notes: Redshift’s NULLIF ignores trailing spaces in some string comparisons, unlike Snowflake. Therefore, the transformation adds RTRIM for equivalence. |
Data type formatting functions¶
Data type formatting functions provide an easy way to convert values from one data type to another. For each of these functions, the first argument is always the value to be formatted and the second argument contains the template for the new format. (Redshift SQL Language Reference Data type formatting functions).
Redshift |
Snowflake |
---|---|
Notes: Snowflake’s support for this function is partial (see SSC-EWI-0006). |
|
Notes: Snowflake’s |
Date and time functions¶
Redshift |
Snowflake |
---|---|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
CONVERT_TIMEZONE ( <source_tz> , <target_tz> , <source_timestamp_ntz> ) CONVERT_TIMEZONE ( <target_tz> , <source_timestamp> ) Notes: Redshift defaults to UTC; the Snowflake function requires explicit UTC specification. Therefore, it will be added as the target timezone. |
|
DATEADD/DATE_ADD ( datepart, interval, {date | time | timetz | timestamp} ) |
DATE_ADD ( <date_or_time_part>, <value>, <date_or_time_expr> ) Notes: Invalid date part formats are translated to Snowflake-compatible formats. |
Notes: Invalid date part formats are translated to Snowflake-compatible formats. |
|
Notes: this function is partially supported by Snowflake. (See SSC-EWI-OOO6). |
|
DATE_PART_YEAR (date) |
YEAR ( <date_or_timestamp_expr> ) Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
Notes: Invalid date part formats are translated to Snowflake-compatible formats. |
|
GETDATE() |
GETDATE() |
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
SYSDATE() |
|
EXTRACT |
Note
Redshift timestamps default to microsecond precision (6 digits); Snowflake defaults to nanosecond precision (9 digits). Adjust precision as needed using ALTER SESSION (e.g., ALTER SESSION SET TIMESTAMP_OUTPUT_FORMAT = 'YYYY-MM-DD HH24:MI:SS.FF2';
). Precision loss may occur depending on the data type used.
Since some formats are incompatible with Snowflake, adjusting the account parameters DATE_INPUT_FORMAT or TIME_INPUT_FORMAT might maintain functional equivalence between platforms.
Hash Functions¶
A hash function is a mathematical function that converts a numerical input value into another value. (Redshift SQL Language Reference Hash functions).
Redshift |
Snowflake |
---|---|
FNV_HASH (value [, seed]) |
HASH ( <expr> [ , <expr> … ] |
JSON Functions¶
Redshift |
Snowflake |
---|---|
Notes:
|
Math functions¶
Redshift |
Snowflake |
---|---|
DLOG10 (number) |
LOG (10, number) |
Note
Redshift and Snowflake results may differ in scale.
String functions¶
String functions process and manipulate character strings or expressions that evaluate to character strings. (Redshift SQL Language Reference String functions).
Redshift |
Snowflake |
---|---|
Notes: For negative lengths in |
|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
QUOTE_IDENT (string) |
CONCAT (‘”’, string, ‘”’) |
Notes: This function includes a |
|
Notes: Certain special characters, the results may vary between platforms (See SSC-FDM-PG0013). |
|
Notes: Snowflake and Redshift handle SPLIT_PART differently with case-insensitive collations. |
|
STRPOS (string, substring ) |
POSITION ( <expr1> IN <expr> ) |
Notes: Snowflake partially supports this function. Redshift’s |
|
Notes: Redshift uses keywords (BOTH, LEADING, TRAILING) for trim; Snowflake uses TRIM, LTRIM, RTRIM. |
|
SUPER type information functions¶
Redshift |
Snowflake |
---|---|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
Window functions¶
Redshift |
Snowflake |
---|---|
Notes: AVG rounding/formatting can vary by data type between Redshift and Snowflake. |
|
Notes: ORDER BY is mandatory in Snowflake; missing clauses are replaced with |
|
Notes: Snowflake needs ORDER BY; missing clauses get |
|
Notes: Snowflake needs ORDER BY; missing clauses get |
|
Notes: Redshift allows constant or expression offsets; Snowflake allows only constant offsets. |
|
Notes: Redshift’s DISTINCT ignores trailing spaces (‘a ‘ = ‘a’); Snowflake’s does not. (See SSC-FDM-PG0013). |
|
Notes: Snowflake does not allow the use of date types, while Redshift does. (See SSC-FDM-PG0013). |
|
Notes: ORDER BY is mandatory in Snowflake; missing clauses are replaced with |
|
Notes: ORDER BY is mandatory in Snowflake; missing clauses are replaced with |
|
Notes: ORDER BY is mandatory in Snowflake; missing clauses are replaced with |
|
Notes: Rounding varies between platforms. |
|
Notes: the results may vary between platforms (See SSC-FDM-PG0013). |
|
Notes: ORDER BY is mandatory in Snowflake; missing clauses are replaced with |
|
STDDEV |
|
VARIANCE |
Known Issues ¶
For more information about quoted identifiers in functions, click here.
IDENTITY¶
Description ¶
The IDENTITY function is a system function that operates on a specified column of a table to determine the initial value for the identity. If the initial value is not available, it defaults to the value provided in the function. This will be translation to a Sequence in Snowflake.
Grammar Syntax ¶
"identity"(oid_id, oid_table_id, default)
Note
This function is no longer supported in Redshift. It uses the default value to define the identity and behaves like a standard identity column.
Sample Source Patterns¶
Input Code:¶
Redshift¶
CREATE TABLE IF NOT EXISTS table_test
(
id integer,
inventory_combo BIGINT DEFAULT "identity"(850178, 0, '5,3'::text)
);
INSERT INTO table_test (id) VALUES
(1),
(2),
(3),
(4);
SELECT * FROM table_test;
Results¶
id |
inventory_combo |
---|---|
1 |
5 |
2 |
8 |
3 |
11 |
3 |
14 |
Output Code:
Snowflake¶
CREATE TABLE IF NOT EXISTS table_test
(
id integer,
inventory_combo BIGINT IDENTITY(5,3) ORDER
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/13/2024", "domain": "test" }}';
INSERT INTO table_test (id) VALUES
(1),
(2),
(3),
(4);
SELECT * FROM
table_test;
Results¶
id |
inventory_combo |
---|---|
1 |
5 |
2 |
8 |
3 |
11 |
3 |
14 |
Related EWIs¶
There are no known issues.
TO_CHAR¶
Date function
Description¶
TO_CHAR converts a timestamp or numeric expression to a character-string data format. (Redshift SQL Language Reference TO_CHAR function)
Warning
This function is partially supported in Snowflake.
For more information about quoted identifiers in functions, click here.
Grammar Syntax¶
TO_CHAR(timestamp_expression | numeric_expression , 'format')
Sample Source Patterns¶
Input Code:¶
Redshift¶
SELECT TO_CHAR(timestamp '2009-12-31 23:15:59', 'YYYY'),
TO_CHAR(timestamp '2009-12-31 23:15:59', 'YYY'),
TO_CHAR(timestamp '2009-12-31 23:15:59', 'TH'),
"to_char"(timestamp '2009-12-31 23:15:59', 'MON-DY-DD-YYYY HH12:MIPM'),
TO_CHAR(125.8, '999.99'),
"to_char"(125.8, '999.99');
Results¶
TO_CHAR |
TO_CHAR |
TO_CHAR |
TO_CHAR |
TO_CHAR |
---|---|---|---|---|
2009 |
009 |
DEC-THU-31-2009 11:15PM |
125.80 |
125.80 |
Output Code:¶
Snowflake¶
SELECT
TO_CHAR(timestamp '2009-12-31 23:15:59', 'YYYY'),
PUBLIC.YEAR_PART_UDF(timestamp '2009-12-31 23:15:59', 3),
TO_CHAR(timestamp '2009-12-31 23:15:59', 'TH') !!!RESOLVE EWI!!! /*** SSC-EWI-0006 - TH FORMAT MAY FAIL OR MAY HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/!!!,
PUBLIC.MONTH_SHORT_UDF(timestamp '2009-12-31 23:15:59', 'uppercase') || '-' || PUBLIC.DAYNAME_SHORT_UDF(timestamp '2009-12-31 23:15:59', 'uppercase') || TO_CHAR(timestamp '2009-12-31 23:15:59', '-DD-YYYY HH12:MI') || PUBLIC.MERIDIAN_INDICATORS_UDF(timestamp '2009-12-31 23:15:59', 'uppercase'),
TO_CHAR(125.8, '999.99'),
TO_CHAR(125.8, '999.99');
Results¶
TO_CHAR |
TO_CHAR |
---|---|
2009 |
Dec-Thu-31-2009 11:15PM |
Known Issues ¶
No issues were found.
Related EWIs¶
SSC-EWI-0006: The current date/numeric format may have a different behavior in Snowflake.
For datetime values¶
Translation specification for the TO_CHAR function when transforming date or timestamp values to string
Description¶
The following format strings apply to functions such as TO_CHAR. These strings can contain datetime separators (such as ‘
-
’, ‘/
’, or ‘:
’) and the following “dateparts” and “timeparts”. (Redshift Datetime format strings reference page)
Grammar Syntax¶
TO_CHAR (timestamp_expression, 'format')
The following table specifies the mapping of each format element to Snowflake:
Redshift |
Snowflake |
---|---|
|
|
|
|
|
|
|
Directly supported |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
Notes: For this UDF to work correctly the Snowflake session parameter |
|
|
|
|
|
Directly supported |
|
|
|
Directly supported |
|
Directly supported |
|
Directly supported |
|
|
|
|
|
|
|
|
|
Notes: According to the redshift documentation, all timestamp with time zone are stored in UTC, which causes this format element to return a fixed result. |
|
+00 Notes: According to the redshift documentation, all timestamp with time zone are stored in UTC, which causes this format element to return a fixed result. |
|
|
|
Notes: This is a PostgreSQL template pattern modifier for “spell mode”, however it does nothing on Redshift, so it is removed from the output. |
|
Notes: This is another template pattern modifier for “fixed format”, however it has no use on the TO_CHAR function so it is removed. |
Sample Source Patterns¶
Direct format elements transformation (no functions/UDFs)¶
The result is preserved as a single TO_CHAR function
Redshift¶
Query¶
SELECT TO_CHAR('2013-10-03 13:50:15.456871'::TIMESTAMP, 'DD/MM/YY HH:MI:SS.MS') AS col1;
Result¶
+----------------------+
|col1 |
+----------------------+
|03/10/13 01:50:15.456 |
+----------------------+
Snowflake¶
Query¶
SELECT TO_CHAR('2013-10-03 13:50:15.456871'::TIMESTAMP, 'DD/MM/YY HH12:MI:SS.FF3') AS col1;
Result¶
+----------------------+
|col1 |
+----------------------+
|03/10/13 01:50:15.456 |
+----------------------+
Format transformation using functions/UDFs¶
The result is a concatenation of multiple TO_CHAR, UDFs and Snowflake built-in functions that generate the equivalent string representation of the datetime value
Redshift¶
Query¶
SELECT TO_CHAR(DATE '2025-07-05', '"Today is " Month DAY DD, "it belongs to the week " IW') AS result;
Result¶
+-------------------------------------------------------------+
|result |
+-------------------------------------------------------------+
|Today is July SATURDAY 05, it belongs to the week 27 |
+-------------------------------------------------------------+
Snowflake¶
Query¶
SELECT
'Today is ' ||
TO_CHAR(DATE '2025-07-05', ' ') ||
PUBLIC.FULL_MONTH_NAME_UDF(DATE '2025-07-05', 'firstOnly') ||
' ' ||
PUBLIC.DAYNAME_LONG_UDF(DATE '2025-07-05', 'uppercase') ||
TO_CHAR(DATE '2025-07-05', ' DD, ') ||
'it belongs to the week ' ||
TO_CHAR(DATE '2025-07-05', ' ') ||
WEEKISO(DATE '2025-07-05') AS result;
Result¶
+-------------------------------------------------------------+
|result |
+-------------------------------------------------------------+
|Today is July SATURDAY 05, it belongs to the week 27 |
+-------------------------------------------------------------+
Quoted text¶
Format elements in double quoted text are added to the output directly without interpreting them, escaped double quotes are transformed to their Snowflake escaped equivalent.
Redshift¶
Query¶
SELECT
TO_CHAR(DATE '2025-01-16', 'MM "TESTING DD" DD') AS result1,
TO_CHAR(DATE '2025-01-16', 'MM TESTING \\"DD\\" DD') AS result2,
TO_CHAR(DATE '2025-01-16', 'MM "TESTING \\"DD\\"" DD') AS result3;
Result¶
+-----------------+-------------------+-------------------+
|result1 |result2 |result3 |
+-----------------+-------------------+-------------------+
|01 TESTING DD 16 |01 TEST5NG "16" 16 |01 TESTING "DD" 16 |
+-----------------+-------------------+-------------------+
Snowflake¶
Query¶
SELECT
TO_CHAR(DATE '2025-01-16', 'MM ') || 'TESTING DD' || TO_CHAR(DATE '2025-01-16', ' DD') AS result1,
TO_CHAR(DATE '2025-01-16', 'MM TEST') || PUBLIC.ISO_YEAR_PART_UDF(DATE '2025-01-16', 1) || TO_CHAR(DATE '2025-01-16', 'NG ""DD"" DD') AS result2,
TO_CHAR(DATE '2025-01-16', 'MM ') || 'TESTING "DD"' || TO_CHAR(DATE '2025-01-16', ' DD') AS result3;
Result¶
+-----------------+-------------------+-------------------+
|result1 |result2 |result3 |
+-----------------+-------------------+-------------------+
|01 TESTING DD 16 |01 TEST5NG "16" 16 |01 TESTING "DD" 16 |
+-----------------+-------------------+-------------------+
Known Issues¶
Template pattern modifiers not supported¶
The following format template modifiers:
FM (fill mode)
TH and th (uppercase and lowercase ordinal number suffix)
TM (translation mode)
Are not supported, including them in a format will generate SSC-EWI-0006
Input code:
SELECT TO_CHAR(CURRENT_DATE, 'FMMonth'),
TO_CHAR(CURRENT_DATE, 'DDTH'),
TO_CHAR(CURRENT_DATE, 'DDth'),
TO_CHAR(CURRENT_DATE, 'TMMonth');
Output code:
SELECT
TO_CHAR(CURRENT_DATE(), 'FM') || PUBLIC.FULL_MONTH_NAME_UDF(CURRENT_DATE(), 'firstOnly') !!!RESOLVE EWI!!! /*** SSC-EWI-0006 - FMMonth FORMAT MAY FAIL OR MAY HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/!!!,
TO_CHAR(CURRENT_DATE(), 'DDTH') !!!RESOLVE EWI!!! /*** SSC-EWI-0006 - DDTH FORMAT MAY FAIL OR MAY HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/!!!,
TO_CHAR(CURRENT_DATE(), 'DDth') !!!RESOLVE EWI!!! /*** SSC-EWI-0006 - DDth FORMAT MAY FAIL OR MAY HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/!!!,
TO_CHAR(CURRENT_DATE(), 'TM') || PUBLIC.FULL_MONTH_NAME_UDF(CURRENT_DATE(), 'firstOnly') !!!RESOLVE EWI!!! /*** SSC-EWI-0006 - TMMonth FORMAT MAY FAIL OR MAY HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/!!!;
Format parameter passed through variable
When the format parameter is passed as a variable instead of a string literal, the transformation of format elements can not be applied, an FDM will be added to the uses of the function warning about it.
Input code:
SELECT TO_CHAR(d, 'YYYY/MM/DD'),
TO_CHAR(d, f)
FROM (SELECT TO_DATE('2001-01-01','YYYY-MM-DD') as d, 'DD/MM/YYYY' as f);
Output code:
SELECT TO_CHAR(d, 'YYYY/MM/DD'),
--** SSC-FDM-0032 - PARAMETER 'format_string' IS NOT A LITERAL VALUE, TRANSFORMATION COULD NOT BE FULLY APPLIED **
TO_CHAR(d, f)
FROM (SELECT TO_DATE('2001-01-01','YYYY-MM-DD') as d, 'DD/MM/YYYY' as f);
Related EWIs¶
SSC-EWI-0006: The current date/numeric format may have a different behavior in Snowflake.
SSC-FDM-0032: Parameter is not a literal value, transformation could not be fully applied