SnowConvert: Redshift Issuses

SSC-EWI-RS0008

Severity

High

Description

This conversion issue is added since In Redshift you can apply the DELETE statement to materialized views used for streaming ingestion (https://docs.aws.amazon.com/redshift/latest/dg/materialized-view-streaming-ingestion.html). In Snowflake, these views are transformed into dynamic tables, and the DELETE statement cannot be used on dynamic tables.

Code Example

Input Code:

CREATE MATERIALIZED VIEW mv AS
SELECT id, name, department FROM employees WHERE department = 'Engineering';

DELETE FROM mv
WHERE id = 2;
Copy

Output Code:

CREATE DYNAMIC TABLE mv
--** SSC-FDM-0031 - DYNAMIC TABLE REQUIRED PARAMETERS SET BY DEFAULT **
TARGET_LAG='1 day'
WAREHOUSE=UPDATE_DUMMY_WAREHOUSE
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": {  "major": 0,  "minor": 0,  "patch": "0" }, "attributes": {  "component": "redshift",  "convertedOn": "02/11/2025",  "domain": "test" }}'
AS
SELECT id, name, department FROM
        employees
WHERE
        RTRIM( department) = RTRIM( 'Engineering');


!!!RESOLVE EWI!!! /*** SSC-EWI-RS0008 - MATERIALIZED VIEW IS TRANSFORMED INTO A DYNAMIC TABLE, AND THE DELETE STATEMENT CANNOT BE USED ON DYNAMIC TABLES. ***/!!!
DELETE FROM mv
WHERE id = 2;
Copy

Recommendations

  • Because dynamic tables cannot be directly deleted from, you can achieve the same result by replacing the dynamic table definition.

  • If you need more support, you can email us at snowconvert-support@snowflake.com

SSC-EWI-RS0009

Severity

Low

Description

In Snowflake, the MERGE with REMOVE DUPLICATES clause is not supported. To fully support the original code, a workaround is needed. An INSERT WHEN NOT MATCHED clause needs to be generated in the output code, and it requires the source table columns. If the source table was not found during migration, no columns are generated, and an error will be thrown.

Code Example

Input Code:

MERGE INTO target USING source ON target.id = source.id REMOVE DUPLICATES;
Copy

Output Code:

CREATE TEMPORARY TABLE source_duplicates AS
  SELECT DISTINCT
    source.*
  FROM
    source
    INNER JOIN
      target
      ON target.id = source.id;

!!!RESOLVE EWI!!! /*** SSC-EWI-RS0009 - SEMANTIC INFORMATION NOT FOUND FOR THE SOURCE TABLE. COLUMNS TO BE INSERTED MAY BE ADDED MANUALLY. ***/!!!
MERGE INTO target
USING source ON target.id = source.id
WHEN MATCHED THEN
  DELETE
WHEN NOT MATCHED THEN
  INSERT
  VALUES ();

INSERT INTO target
SELECT
  *
FROM
  source_duplicates;

DROP TABLE IF EXISTS source_duplicates CASCADE;
Copy

Recommendations

  • Search to see if the source table is present in the migrated code and manually add the columns in the insert operation.

  • If you need more support, you can email us at snowconvert-support@snowflake.com


SSC-EWI-RS0002

Severity

Medium

Description

The use of SET configuration parameter (https://docs.aws.amazon.com/es_es/redshift/latest/dg/r_CREATE_PROCEDURE.html) is not supported by Snowflake. For more information please refer to CREATE PROCEDURE documentation.

Code Examples

Input Code:

CREATE OR REPLACE PROCEDURE procedure2(
    IN input_param INTEGER,
    OUT output_param NUMERIC
)
AS $$
BEGIN
    output_param := input_param * 1.7;
END;
$$
LANGUAGE plpgsql
SET enable_numeric_rounding to ON;
Copy

Output Code:

CREATE OR REPLACE PROCEDURE procedure2 (
    IN !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'InParameterMode' NODE ***/!!! input_param INTEGER,
    OUT output_param NUMERIC
)
RETURNS VARCHAR
LANGUAGE SQL
!!!RESOLVE EWI!!! /*** SSC-EWI-RS0002 - SET CONFIGURATION PARAMETER 'enable_numeric_rounding' IS NOT SUPPORTED IN SNOWFLAKE. ***/!!!
SET enable_numeric_rounding to ON
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": {  "major": 0,  "minor": 0,  "patch": "0" }, "attributes": {  "component": "redshift",  "convertedOn": "09/17/2024" }}'
AS $$
BEGIN
    output_param := input_param * 1.7;
END;
$$;
Copy

Recommendations


SSC-EWI-RS0003

Severity

Medium

Description

Redshift documentation for CREATE VIEW includes an optional clause that specifies that the particular view is not bound to the database objects such as tables or functions, nor to those objects that it is referencing. The documentation also clarifies that in such cases that this clause is used, the referenced objects must be qualified with a schema name. This clause allows to create a view and reference objects that might not exist yet. Their existence will be verified once the view is queried, but not at its definition.

However, there is no equivalent command nor obvious workaround to implement this functionality in Snowflake, furthermore, the Snowflake documentation suggests that the views are linked to a specific schema and so are the referenced objects in the view.

If the references linked to the View are present in the input code, the statement will be removed without issue. However, if the necessary references are missing, a warning message will be added to inform the user that the statement cannot be removed due to the missing references.

SnowConvert performs analysis solely on the input code and does not account for objects already deployed in Snowflake. Therefore the output may have some issues pointing to missing references, if the references are already present in the Snowflake database, the user can safely remove the statement without any issues.

Code Examples

Input Code:

CREATE VIEW myView AS SELECT col1 FROM public.missingTable
WITH NO SCHEMA BINDING;
Copy

Output Code:

--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "public.missingTable" **
CREATE VIEW myView
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": {  "major": 0,  "minor": 0,  "patch": "0" }, "attributes": {  "component": "redshift",  "convertedOn": "09/17/2024" }}'
AS SELECT col1 FROM
public.missingTable
!!!RESOLVE EWI!!! /*** SSC-EWI-RS0003 - WITH NO SCHEMA BINDING STATEMENT CAN NOT BE REMOVED DUE TO MISSING REFERENCES. ***/!!!
WITH NO SCHEMA BINDING;
Copy

Recommendations

  • To resolve this issue, it is suggested to add the missing references to the input code, if the object is already deployed in the Snowflake database, the statement can be remove without issue.

  • If you need more support, you can email us at snowconvert-support@snowflake.com


SSC-EWI-RS0004

Severity

High

Description

This conversion issue is added because the HLLSKETCH data type is not supported in Snowflake.

Code Example

Input Code:

CREATE TABLE table1
(
    col_hllsketch HLLSKETCH
);
Copy

Output Code:

CREATE TABLE table1
(
    col_hllsketch HLLSKETCH !!!RESOLVE EWI!!! /*** SSC-EWI-RS0004 - HLLSKETCH DATA TYPE NOT SUPPORTED IN SNOWFLAKE. ***/!!!
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": {  "major": 0,  "minor": 0,  "patch": "0" }, "attributes": {  "component": "redshift",  "convertedOn": "09/17/2024" }}';
Copy

Recommendations


SSC-EWI-RS0005

Severity

High

Description

This conversion issue is added because the column aliases cannot be used in the IN clause of the PIVOT/UNPIVOT query in Snowflake.

Code Example

Input Code:

SELECT *
FROM count_by_color UNPIVOT (
    cnt FOR color IN (red AS r, green AS g, blue AS b)
);
Copy

Output Code:

SELECT *
FROM
    count_by_color UNPIVOT (
    cnt FOR color IN (red
                          !!!RESOLVE EWI!!! /*** SSC-EWI-RS0005 - COLUMN ALIASES CANNOT BE USED IN THE IN CLAUSE OF THE PIVOT/UNPIVOT QUERY IN SNOWFLAKE. ***/!!! AS r, green
                                                                                                                                                                              !!!RESOLVE EWI!!! /*** SSC-EWI-RS0005 - COLUMN ALIASES CANNOT BE USED IN THE IN CLAUSE OF THE PIVOT/UNPIVOT QUERY IN SNOWFLAKE. ***/!!! AS g, blue
                                                                                                                                                                                                                                                                                                                                 !!!RESOLVE EWI!!! /*** SSC-EWI-RS0005 - COLUMN ALIASES CANNOT BE USED IN THE IN CLAUSE OF THE PIVOT/UNPIVOT QUERY IN SNOWFLAKE. ***/!!! AS b)
);
Copy

Recommendations


SSC-EWI-RS0001

Severity

Medium

Description

Redshift CREATE PROCEDURE includes an optional clause that specifies the NONATOMIC transaction mode. Snowflake does not have an equivalent keyword to reproduce the behavior as it is defined, when possible, the functionality is emulated in Snowflake by doing changes in the final code.

The only behavior that must be manually checked is that a procedure defined as NONATOMIC automatically commits the statements inside the procedure. To reproduce this behavior, Snowflake supports “autocommit” as an account parameter, more information about it here.

Code Examples

Input Code:

CREATE OR REPLACE PROCEDURE procedure1(parameter int)
Nonatomic
AS
   $$
      SELECT * from my_table;
   $$
LANGUAGE plpgsql;
Copy

Output Code:

CREATE OR REPLACE PROCEDURE procedure1 (parameter int)
RETURNS VARCHAR
!!!RESOLVE EWI!!! /*** SSC-EWI-RS0001 - THE NONATOMIC OPTION IS NOT SUPPORTED IN SNOWFLAKE. ***/!!!
Nonatomic
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": {  "major": 0,  "minor": 0,  "patch": "0" }, "attributes": {  "component": "redshift",  "convertedOn": "09/17/2024" }}'
AS
   $$
      SELECT * from
         my_table;
   $$;
Copy

Recommendations

Language: English