SnowConvert: Performance Review Messages¶
A Performance Review issue (PRF) will be generated when SnowConvert can convert the code from the source platform into syntactically correct Snowflake code but that code may not have the best performance in the Snowflake environment. If a PRF is present in some part of the output code, it is recommended to carefully review the code and check if it might be possible to rewrite it to have better performance.
SSC-PRF-0006¶
Severity¶
None
Description¶
This message is shown when a cursor definition exists within a query. A cursor expression returns a nested cursor, a nested cursor is implicitly opened when the cursor expression is evaluated. For more information please refer to Oracle Cursor Expression.
Code examples¶
SELECT
category_id,
category_name,
CURSOR (
SELECT
product_id,
product_name || ', ' || category_id
FROM
products e
WHERE
e.category_id = d.category_id
) EMP_CUR
FROM
categories d;
SELECT
category_id,
category_name,
--** SSC-PRF-0006 - NESTED CURSOR INSIDE QUERY IS NOT SUPPORTED IN SNOWFLAKE. **
CURSOR
!!!RESOLVE EWI!!! /*** SSC-EWI-0108 - THE FOLLOWING SUBQUERY MATCHES AT LEAST ONE OF THE PATTERNS CONSIDERED INVALID AND MAY PRODUCE COMPILATION ERRORS ***/!!! (
SELECT
product_id,
NVL(
product_name :: STRING, '') || ', ' || NVL(category_id :: STRING, '')
FROM
products e
WHERE
e.category_id = d.category_id
) EMP_CUR
FROM
categories d;
Recommendations¶
Avoid them whenever possible due to their potential impact on performance and code complexity.
Remove the use of nested cursors, instead, you can use SQL functions, joins, subqueries, window functions, common table expressions (CTEs), recursive queries, and other features to process bulk data and avoid the need for nested cursors.
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-0002¶
Description¶
Using collation in Snowflake can affect the performance of queries, specially when used inside WHERE clauses, for more information on how collation affects performance please check the Performance Implications of Using Collation.
This warning is generated to point out that a column is created with case insensitive collation, any use of this column in queries may result in a performance degradation.
Code examples¶
CREATE TABLE exampleTable
(
col1 CHAR(10),
col2 CHAR(20) COLLATE 'en-ci' /*** SSC-PRF-0002 - CASE INSENSITIVE COLUMNS CAN DECREASE THE PERFORMANCE OF QUERIES ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"teradata"}}'
;
Oracle¶
CREATE TABLE exampleTable (
col1 VARCHAR(50) COLLATE BINARY_CI,
col2 VARCHAR(50) COLLATE BINARY_CS
);
CREATE OR REPLACE TABLE exampleTable (
col1 VARCHAR(50) COLLATE BINARY_CI /*** SSC-PRF-0002 - CASE INSENSITIVE COLUMNS CAN DECREASE THE PERFORMANCE OF QUERIES ***/,
col2 VARCHAR(50) COLLATE BINARY_CS
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
SQL Server¶
CREATE TABLE exampleTable (
col1 VARCHAR(50) COLLATE Latin1_General_CI_AS,
col2 VARCHAR(50) COLLATE Latin1_General_CS_AS
);
CREATE OR REPLACE TABLE exampleTable (
col1 VARCHAR(50) COLLATE 'EN-CI-AS' /*** SSC-PRF-0002 - CASE INSENSITIVE COLUMNS CAN DECREASE THE PERFORMANCE OF QUERIES ***/,
col2 VARCHAR(50) COLLATE 'EN-CS-AS'
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"transact"}}'
;
Recommendations¶
Analyze the impact of using case-insensitive collation on the performance of your application, if it is severely affected then consider refactoring your code to avoid using it, if the performance level is tolerable then this warning can be safely ignored.
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-0003¶
Severity¶
Low
Description¶
This warning is used to indicate that a FETCH
statement was found inside a loop. This statement allows one to retrieve rows from a result set one at a time and perform some processing on each row.
This scenario could be considered a complex pattern when it involves processing a large number of rows or requires complex logic to handle the data. E.g. if the cursor fetch inside a loop construct requires joining multiple tables or performing complex calculations on the data, it can become difficult to manage and may not scale well for large datasets.
Code Example¶
Teradata¶
REPLACE PROCEDURE teradata_fetch_inside_loop()
DYNAMIC RESULT SETS 1
BEGIN
DECLARE col_name VARCHAR(200);
DECLARE col_int INTEGER DEFAULT 0;
DECLARE cursor_var CURSOR FOR SELECT some_column FROM tabla1;
WHILE (col_int <> 0) DO
FETCH cursor_var INTO col_name;
SET col_int = col_int + 1;
END WHILE;
END;
--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "tabla1" **
CREATE OR REPLACE PROCEDURE teradata_fetch_inside_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "teradata", "convertedOn": "07/04/2024" }}'
EXECUTE AS CALLER
AS
$$
DECLARE
col_name VARCHAR(200);
col_int INTEGER DEFAULT 0;
BEGIN
LET cursor_var CURSOR
FOR
SELECT
some_column FROM
tabla1;
WHILE (col_int <> 0) LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH cursor_var INTO col_name;
col_int := col_int + 1;
END LOOP;
END;
$$;
Oracle¶
CREATE PROCEDURE oracle_fetch_inside_loop
IS
var1 table1.column1%TYPE;
CURSOR cursor1 IS SELECT COLUMN_NAME FROM table1;
BEGIN
WHILE true LOOP
FETCH cursor1 INTO var1;
EXIT WHEN cursor1%NOTFOUND;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE oracle_fetch_inside_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
var1 VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'table1.column1%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!;
cursor1 CURSOR
FOR
SELECT COLUMN_NAME FROM
table1;
BEGIN
WHILE (true) LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH cursor1 INTO
:var1;
IF (var1 IS NULL) THEN
EXIT;
END IF;
END LOOP;
END;
$$;
SQL Server¶
CREATE OR ALTER PROCEDURE transact_fetch_inside_loop
AS
BEGIN
DECLARE cursor1 CURSOR
FOR SELECT col1 FROM my_table;
WHILE 1=0
BEGIN
FETCH NEXT FROM @cursor1 INTO @variable1;
END
END;
CREATE OR REPLACE PROCEDURE transact_fetch_inside_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"transact"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
--** SSC-FDM-TS0013 - SNOWFLAKE SCRIPTING CURSOR ROWS ARE NOT MODIFIABLE **
cursor1 CURSOR
FOR
SELECT
col1
FROM
my_table;
BEGIN
WHILE (1=0) LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH
CURSOR1
INTO
:VARIABLE1;
END LOOP;
END;
$$;
Recommendations¶
One way to avoid turning into a complex pattern is to use set-based operations instead of a loop. This means using SQL statements like SELECT, UPDATE, and DELETE with appropriate WHERE clauses to operate on sets of rows at a time, rather than looping through individual rows. This is a workaround for this:
CREATE OR REPLACE PROCEDURE cursor_fetch_inside_loop
AS
record_employee employees%rowtype;
CURSOR emp_cursor IS SELECT * FROM employees;
BEGIN
OPEN emp_cursor;
LOOP
FETCH emp_cursor INTO record_employee;
EXIT WHEN emp_cursor%notfound;
INSERT INTO new_employees VALUES (record_employee.first_name, record_employee.last_name);
END LOOP;
CLOSE emp_cursor;
END;
CREATE OR REPLACE PROCEDURE cursor_fetch_inside_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
record_employee OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWTYPE DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
emp_cursor CURSOR
FOR
SELECT
OBJECT_CONSTRUCT( *) sc_cursor_record FROM
employees;
BEGIN
OPEN emp_cursor;
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH emp_cursor INTO
:record_employee;
IF (record_employee IS NULL) THEN
EXIT;
END IF;
INSERT INTO new_employees
SELECT
:record_employee:FIRST_NAME,
:record_employee:LAST_NAME;
END LOOP;
CLOSE emp_cursor;
END;
$$;
Could be used set-based operations.
CREATE OR REPLACE PROCEDURE cursor_fetch_inside_loop AS
BEGIN
INSERT INTO new_employees (first_name, last_name)
SELECT first_name, last_name FROM employees;
END;
Could be used set-based operations.
CREATE OR REPLACE PROCEDURE cursor_fetch_inside_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
INSERT INTO new_employees(first_name, last_name)
SELECT first_name, last_name FROM
employees;
END;
$$;
Recommendations¶
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-0007¶
Description¶
Marks where the usage of CLUSTER BY may cause performance issues.
Example Code¶
Teradata:¶
CREATE MULTISET TABLE T_2008,
NO FALLBACK,
NO BEFORE JOURNAL,
NO AFTER JOURNAL,
CHECKSUM = DEFAULT,
DEFAULT MERGEBLOCKRATIO
(
COL1 NUMBER(20,0) NOT NULL,
COL2 INTEGER,
COL3 VARCHAR(4) CHARACTER SET LATIN NOT CASESPECIFIC,
COL4 DATE FORMAT 'YYYY-MM-DD'
)
PRIMARY INDEX
(
COL1, COL2
)
PARTITION BY ( RANGE_N(COL4 BETWEEN DATE '2010-01-01' AND DATE '2025-12-31' EACH INTERVAL '1' YEAR ),
CASE_N(
COL3 = 'T',
COL3 = 'M',
COL3 = 'L') ); -- PARTITION BY transformed to CLUSTER BY
Snowflake:¶
CREATE OR REPLACE TABLE T_2008
(
COL1 NUMBER(20,0) NOT NULL,
COL2 INTEGER,
COL3 VARCHAR(4) COLLATE 'en-cs',
COL4 DATE
)
--** SSC-PRF-0007 - PERFORMANCE REVIEW - CLUSTER BY **
CLUSTER BY (
!!!RESOLVE EWI!!! /*** SSC-EWI-0031 - RANGE_N FUNCTION NOT SUPPORTED ***/!!!
RANGE_N(COL4 BETWEEN DATE '2010-01-01' AND DATE '2025-12-31' EACH INTERVAL '1' YEAR ),
!!!RESOLVE EWI!!! /*** SSC-EWI-0031 - CASE_N FUNCTION NOT SUPPORTED ***/!!!
CASE_N(
COL3 = 'T',
COL3 = 'M',
COL3 = 'L'))
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "teradata", "convertedOn": "12/16/2024", "domain": "test" }}'
; -- PARTITION BY transformed to CLUSTER BY
Transact:¶
CREATE TABLE my_table (
enterprise_cif INT,
name NVARCHAR(100),
address NVARCHAR(255),
created_at DATETIME
)
WITH (
DISTRIBUTION = HASH(enterprise_cif),
CLUSTERED INDEX (enterprise_cif)
);
Snowflake:¶
CREATE OR REPLACE TABLE my_table (
enterprise_cif INT,
name VARCHAR(100),
address VARCHAR(255),
created_at TIMESTAMP_NTZ(3)
)
--** SSC-PRF-0007 - PERFORMANCE REVIEW - CLUSTER BY **
CLUSTER BY (enterprise_cif)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "transact", "convertedOn": "10/09/2024" }}'
;
Recommendations¶
Review the code in order to identify possible performance issues. More information about this topic can be read here.
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-0004¶
Severity¶
None
Description¶
This warning is used to indicate that the statement has usages of cursor for loop. A cursor for loop is a control structure that allows to iterate over the result set one row at a time.
This scenario could be considered a complex pattern when the code inside the loop is overly complex. E.g. if the SELECT statement inside the cursor for loop returns a large result set, or if the code inside the loop involves complex operations or nested loops, the cursor for loop could become slow and inefficient. This warning is meant to be a helper to spot some problems that a static-code analyzer such as SnowConvert cannot.
Code Example¶
Teradata¶
REPLACE PROCEDURE teradata_cursor_for_loop()
BEGIN
FOR fUsgClass AS cUsgClass CURSOR FOR
(SELECT col1
FROM sample_table)
DO
SET var1 = fUsgClass.col1;
END FOR;
END;
CREATE OR REPLACE PROCEDURE teradata_cursor_for_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"teradata"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
LET cUsgClass CURSOR
FOR
SELECT
col1
FROM
sample_table;
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR fUsgClass IN cUsgClass DO
var1 := :temp_fUsgClass_col1;
END FOR;
END;
$$;
Oracle¶
CREATE OR REPLACE PROCEDURE oracle_cursor_for_loop AS
BEGIN
FOR r1 IN (SELECT col1 FROM sample_table) LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE oracle_cursor_for_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
LET temporary_for_cursor_0 CURSOR
FOR
(SELECT col1 FROM
sample_table
);
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR r1 IN temporary_for_cursor_0 DO
NULL;
END FOR;
END;
$$;
Recommendations¶
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-0005¶
Note
Some parts of the output code are omitted for clarity reasons.
Severity¶
None
Description¶
This warning is used to indicate that the statement has usages of nested cursors. A cursor is a database object that allows traversing and manipulating result sets in a database. When nested cursors are used, it means that one cursor is nested inside the loop of another cursor.
The use of nested cursors can have a significant impact on performance, especially with large result sets. Each cursor operation requires a round trip to the database server, which can increase overhead and slow down execution.
Code examples¶
SQL Server¶
CREATE OR ALTER PROCEDURE procedureSample
AS
BEGIN
DECLARE
@outer_category_id INT,
@outer_category_name NVARCHAR(50),
@inner_product_name NVARCHAR(50);
-- Define the outer cursor
DECLARE outer_cursor CURSOR FOR
SELECT category_id, category_name FROM categories;
-- Open the outer cursor
OPEN @outer_cursor;
-- Fetch the first row from the outer cursor
FETCH NEXT FROM outer_cursor INTO @outer_category_id, @outer_category_name;
-- Start the outer loop
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT 'Category: ' + @outer_category_name;
-- Define the inner cursor
DECLARE inner_cursor CURSOR FOR
SELECT product_name FROM products WHERE category_id = @outer_category_id;
-- Open the inner cursor
OPEN inner_cursor;
FETCH NEXT FROM inner_cursor INTO @inner_product_name;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT 'Product: ' + @inner_product_name + ' Category: ' + CAST(@outer_category_id AS NVARCHAR(10));
-- Fetch the next row from the inner cursor
FETCH NEXT FROM inner_cursor INTO @inner_product_name;
END;
-- Close the inner cursor
CLOSE inner_cursor;
DEALLOCATE inner_cursor;
-- Fetch the next row from the outer cursor
FETCH NEXT FROM outer_cursor INTO @outer_category_id, @outer_category_name;
END;
-- Close the outer cursor
CLOSE outer_cursor;
DEALLOCATE outer_cursor;
END;
CREATE OR REPLACE PROCEDURE procedureSample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"transact"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
OUTER_CATEGORY_ID INT;
OUTER_CATEGORY_NAME VARCHAR(50);
INNER_PRODUCT_NAME VARCHAR(50);
-- Define the outer cursor
--** SSC-FDM-TS0013 - SNOWFLAKE SCRIPTING CURSOR ROWS ARE NOT MODIFIABLE **
outer_cursor CURSOR
FOR
SELECT
category_id,
category_name
FROM
categories;
-- Define the inner cursor
--** SSC-FDM-TS0013 - SNOWFLAKE SCRIPTING CURSOR ROWS ARE NOT MODIFIABLE **
inner_cursor CURSOR
FOR
SELECT
product_name
FROM
products
WHERE
category_id = :OUTER_CATEGORY_ID;
BEGIN
-- Open the outer cursor
--** SSC-PRF-0005 - THE STATEMENT BELOW HAS USAGES OF NESTED CURSORS. **
OPEN OUTER_CURSOR;
-- Fetch the first row from the outer cursor
FETCH
outer_cursor
INTO
:OUTER_CATEGORY_ID,
:OUTER_CATEGORY_NAME;
-- Start the outer loop
-- Define the inner cursor
WHILE (:FETCH_STATUS = 0) LOOP
!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'PRINT' NODE ***/!!!
PRINT 'Category: ' + @outer_category_name;
-- Open the inner cursor
OPEN inner_cursor;
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH
inner_cursor
INTO
:INNER_PRODUCT_NAME;
WHILE (:FETCH_STATUS = 0) LOOP
!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'PRINT' NODE ***/!!!
PRINT 'Product: ' + @inner_product_name + ' Category: ' + CAST(@outer_category_id AS NVARCHAR(10));
-- Fetch the next row from the inner cursor
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH
inner_cursor
INTO
:INNER_PRODUCT_NAME;
END LOOP;
-- Close the inner cursor
CLOSE inner_cursor;
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'DEALLOCATE' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
DEALLOCATE inner_cursor;
-- Fetch the next row from the outer cursor
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH
outer_cursor
INTO
:OUTER_CATEGORY_ID,
:OUTER_CATEGORY_NAME;
END LOOP;
-- Close the outer cursor
CLOSE outer_cursor;
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'DEALLOCATE' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
DEALLOCATE outer_cursor;
END;
$$;
Oracle¶
Explicit cursor¶
CREATE OR REPLACE PROCEDURE procedureSample AS
BEGIN
DECLARE
CURSOR outer_cursor IS
SELECT category_id, category_name FROM categories;
CURSOR inner_cursor (p_category_id NUMBER) IS
SELECT product_name FROM products WHERE category_id = p_category_id;
outer_category_id categories.category_id%TYPE;
outer_category_name categories.category_name%TYPE;
inner_product_name products.product_name%TYPE;
BEGIN
OPEN outer_cursor;
FETCH outer_cursor INTO outer_category_id, outer_category_name;
LOOP
EXIT WHEN outer_cursor%NOTFOUND;
DBMS_OUTPUT.PUT_LINE('Category: ' || outer_category_name);
OPEN inner_cursor(outer_category_id);
LOOP
FETCH inner_cursor INTO inner_product_name;
EXIT WHEN inner_cursor%NOTFOUND;
DBMS_OUTPUT.PUT_LINE('Product: ' || inner_product_name || ' Category: ' || outer_category_id);
END LOOP;
CLOSE inner_cursor;
FETCH outer_cursor INTO outer_category_id, outer_category_name;
END LOOP;
CLOSE outer_cursor;
END;
END;
CREATE OR REPLACE PROCEDURE procedureSample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
DECLARE
outer_cursor CURSOR
FOR
SELECT category_id, category_name FROM
categories;
inner_cursor CURSOR
FOR
SELECT product_name FROM
products
WHERE category_id = ?;
outer_category_id VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'categories.category_id%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!;
outer_category_name VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'categories.category_name%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!;
inner_product_name VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'products.PRODUCT_NAME%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!;
call_results VARIANT;
BEGIN
--** SSC-PRF-0005 - THE STATEMENT BELOW HAS USAGES OF NESTED CURSORS. **
OPEN outer_cursor USING ('DEFAULT VALUE NOT FOUND');
FETCH outer_cursor INTO
:outer_category_id,
:outer_category_name;
LOOP
IF (outer_category_id IS NULL) THEN
EXIT;
END IF;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Category: ' || NVL(:outer_category_name :: STRING, ''))
);
OPEN inner_cursor USING (:outer_category_id);
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH inner_cursor INTO
:inner_product_name;
IF (inner_product_name IS NULL) THEN
EXIT;
END IF;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Product: ' || NVL(:inner_product_name :: STRING, '') || ' Category: ' || NVL(:outer_category_id :: STRING, ''))
);
END LOOP;
CLOSE inner_cursor;
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH outer_cursor INTO
:outer_category_id,
:outer_category_name;
END LOOP;
CLOSE outer_cursor;
RETURN call_results;
END;
END;
$$;
Implicit Cursor¶
CREATE OR REPLACE PROCEDURE procedureSample AS
BEGIN
DECLARE
inner_category_id categories.category_name%TYPE;
inner_product_name products.product_name%TYPE;
inner_cursor SYS_REFCURSOR;
BEGIN
FOR outer_cursor IN (SELECT category_id, category_name FROM categories)
LOOP
OPEN inner_cursor
FOR SELECT product_name, category_id FROM products WHERE category_id = outer_cursor.category_id;
LOOP
FETCH inner_cursor INTO inner_product_name, inner_category_id;
EXIT WHEN inner_cursor%NOTFOUND;
dbms_output.put_line( 'Category id: '|| outer_cursor.category_id);
dbms_output.put_line('Product name: ' || inner_product_name);
END LOOP;
CLOSE inner_cursor;
END LOOP;
END;
END;
CREATE OR REPLACE PROCEDURE procedureSample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
DECLARE
inner_category_id VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'categories.category_name%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!;
inner_product_name VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'products.product_name%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!;
inner_cursor_res RESULTSET;
call_results VARIANT;
BEGIN
LET temporary_for_cursor_0 CURSOR
FOR
(SELECT category_id, category_name FROM
categories
);
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
--** SSC-PRF-0005 - THE STATEMENT BELOW HAS USAGES OF NESTED CURSORS. **
FOR outer_cursor IN temporary_for_cursor_0 DO
LET inner_cursor CURSOR
FOR
SELECT product_name, category_id FROM
products
WHERE category_id = outer_cursor.category_id;
OPEN inner_cursor;
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH inner_cursor INTO
:inner_product_name,
:inner_category_id;
IF (inner_product_name IS NULL) THEN
EXIT;
END IF;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL dbms_output.put_line( 'Category id: ' || NVL(outer_cursor.category_id :: STRING, ''))
);
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL dbms_output.put_line('Product name: ' || NVL(:inner_product_name :: STRING, ''))
);
END LOOP;
CLOSE inner_cursor;
END FOR;
RETURN call_results;
END;
END;
$$;
Recommendations¶
Avoid them whenever possible due to their potential impact on performance and code complexity.
Remove the use of nested cursors, instead, you can use SQL functions, joins, subqueries, window functions, common table expressions (CTEs), recursive queries, and other features to process bulk data and avoid the need for nested cursors.
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-0001¶
Description¶
This warning is used to indicate that the statement has usages of cursor fetch bulk operations. A cursor fetch bulk operation is a way to retrieve multiple rows of data from a cursor in a single fetch operation, rather than fetching rows one at a time. This reduces the overhead of multiple round trips between client and server.
This scenario could be considered a complex pattern if it is used improperly. E.g. fetching too many rows at once can consume a large amount of memory, so it’s important to balance the number of rows fetched with available memory.
Code Example¶
Oracle¶
CREATE OR REPLACE PROCEDURE oracle_cursor_fetch_bulk AS
--cursor and variable declarations
BEGIN
OPEN c1;
FETCH c1 BULK COLLECT INTO col1;
CLOSE c1;
END;
CREATE OR REPLACE PROCEDURE oracle_cursor_fetch_bulk ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
--cursor and variable declarations
$$
BEGIN
OPEN c1;
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
c1 := (
CALL FETCH_BULK_COLLECTION_RECORDS_UDF(:c1)
);
col1 := :c1:RESULT;
CLOSE c1;
END;
$$;
Recommendations¶
If you need more support, you can email us at snowconvert-support@snowflake.com
SSC-PRF-TS0001¶
Description¶
This warning is added to a Common Table Expression (CTE) when SnowConvert did not check for any recursion inside the CTE query definition.
Snowflake SQL supports the RECURSIVE keyword, intended for use along CTE queries that happen to be recursive. SnowConvert currently does not check for that recursion in order to decide if the RECURSIVE keyword should or should not be added to the result, and this warning is shown to make that clear.
Support for this validation might be done in the future as the requirements expand.
Code Example¶
Input Code:¶
WITH Sales_CTE (SalesPersonID, NumberOfOrders)
AS
(
SELECT SalesPersonID, 2
FROM Sales.SalesOrderHeader
WHERE SalesPersonID IS NOT NULL
GROUP BY SalesPersonID
)
SELECT 2 AS "Average Sales Per Person"
FROM Sales_CTE;
Output Code:¶
--** SSC-PRF-TS0001 - PERFORMANCE WARNING - RECURSION FOR CTE NOT CHECKED. MIGHT REQUIRE RECURSIVE KEYWORD **
WITH Sales_CTE (
SalesPersonID,
NumberOfOrders
) AS
(
SELECT
SalesPersonID, 2
FROM
Sales.SalesOrderHeader
WHERE
SalesPersonID IS NOT NULL
GROUP BY
SalesPersonID
)
SELECT 2 AS "Average Sales Per Person"
FROM
Sales_CTE;
Recommendations¶
Not having the RECURSIVE keyword does not impact the result of the query directly, but may impact the way Snowflake uses resources for its execution. We recommend checking Snowflake’s features involving CTEs and contacting us if you would like the RECURSIVE keyword to be automatically added to the CTE queries that support it.
If you need more support, you can email us at snowconvert-support@snowflake.com