SnowConvert: Performance Review Messages¶

A Performance Review (PRF) issue indicates that while SnowConvert successfully translated the source code to valid Snowflake syntax, the resulting code may not perform optimally in Snowflake. When you encounter a PRF issue in the converted code, we recommend reviewing that section carefully and considering whether you can rewrite it to improve performance.

SSC-PRF-0001¶

Description¶

This warning indicates that the statement uses cursor fetch bulk operations. These operations allow you to retrieve multiple rows of data from a cursor at once, instead of one row at a time. Using bulk operations improves performance by reducing the number of communications needed between the client and server.

This pattern can become complex if not implemented correctly. For example, retrieving too many rows in a single fetch operation can consume excessive memory. It’s crucial to maintain a balance between the number of rows fetched and the available memory resources.

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;
Copy
 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;
$$;
Copy

Best Practices¶

SSC-PRF-0002¶

Description¶

Using collation in Snowflake can impact query performance, particularly in WHERE clauses. To learn more about how collation affects performance, please refer to the Performance Implications of Using Collation.

A warning has been generated to indicate that a column was created with case-insensitive collation. Using this column in queries may cause slower performance.

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"}}'
;
Copy

Oracle¶

 CREATE TABLE exampleTable (
    col1 VARCHAR(50) COLLATE BINARY_CI,
    col2 VARCHAR(50) COLLATE BINARY_CS
);
Copy
 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"}}'
   ;
Copy

Microsoft SQL Server¶

 CREATE TABLE exampleTable (
    col1 VARCHAR(50) COLLATE Latin1_General_CI_AS,
    col2 VARCHAR(50) COLLATE Latin1_General_CS_AS
);
Copy
 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"}}'
;
Copy

Best Practices¶

  • If your application’s performance is significantly affected by case-insensitive collation, consider rewriting your code to avoid using it. However, if the performance impact is acceptable, you can ignore this warning.

  • For additional assistance, contact us at snowconvert-support@snowflake.com

SSC-PRF-0003¶

Severity¶

Low

Description¶

This warning appears when a FETCH statement is detected within a loop. The FETCH statement retrieves and processes individual rows from a result set one at a time.

Processing large datasets using cursors within loops can become complex, especially when:

  • Multiple table joins are involved

  • Complex calculations are required

  • Large numbers of rows need to be processed

This pattern may lead to performance issues and can be difficult to maintain as the data volume grows.

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;
Copy
 --** 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;
$$;
Copy

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;
Copy
 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;
$$;
Copy

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;
Copy
 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;
$$;
Copy

Best Practices¶

  • To improve performance and avoid complex patterns, use set-based operations instead of loops. Replace row-by-row processing with SQL statements (SELECT, UPDATE, DELETE) that operate on multiple rows simultaneously using WHERE clauses. This approach is more efficient and easier to maintain.

 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;
Copy
 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;
$$;
Copy

Set-based operations can be used to process data more efficiently.

 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;
Copy

Set-based operations can be used to process data more efficiently.

 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;
$$;
Copy

Best Practices¶

SSC-PRF-0004¶

Severity¶

Description¶

This warning indicates that the statement contains cursor for loops. A cursor for loop is a programming structure that processes query results one row at a time, allowing you to work with individual records from a result set.

This warning helps identify potential performance issues in cursor FOR loops. Performance problems may arise when:

  • The SELECT statement within the cursor returns a large dataset

  • The loop contains complex operations

  • The loop contains nested loops

While SnowConvert can detect these patterns, you should review and optimize the code to ensure efficient execution.

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;
Copy
 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;
$$;
Copy

Oracle¶

 CREATE OR REPLACE PROCEDURE oracle_cursor_for_loop AS
BEGIN
    FOR r1 IN (SELECT col1 FROM sample_table) LOOP
        NULL;
    END LOOP;
END;
Copy
 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;
$$;
Copy

Best Practices¶

SSC-PRF-0005¶

Note

For better readability, we have simplified some sections of the code in this example.

Severity¶

Description¶

This warning indicates that the statement contains nested cursors. A cursor is a database feature that lets you process rows from a query result one at a time. Nested cursors occur when you use one cursor inside another cursor’s loop, which can impact performance and should be used with caution.

Nested cursors can significantly slow down your code’s performance, particularly when working with large amounts of data. This is because each time a cursor operates, it needs to communicate with the database server, creating additional processing overhead and delays.

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;
Copy
 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;
$$;
Copy

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;
Copy
 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;
$$;
Copy

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;
Copy
 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;
$$;
Copy

Best Practices¶

  • Nested cursors should be avoided as they can negatively impact performance and make code more complex.

  • Instead of nested cursors, use SQL features such as:

    • SQL functions

    • Joins

    • Subqueries

    • Window functions

    • Common Table Expressions (CTEs)

    • Recursive queries These alternatives process data in bulk and are more efficient.

  • For additional assistance, contact us at snowconvert-support@snowflake.com

SSC-PRF-0006¶

Severity¶

Description¶

This message appears when a query contains a cursor definition. When a cursor expression is evaluated, it returns and automatically opens a nested cursor. For more details, see 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;
Copy
 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;
Copy

Best Practices¶

  • We recommend avoiding cursors as they can negatively affect performance and make code more complex.

  • Instead of using nested cursors, consider these alternatives:

    • SQL functions

    • Joins

    • Subqueries

    • Window functions

    • Common Table Expressions (CTEs)

    • Recursive queries These options are better for processing large amounts of data efficiently.

  • For additional assistance, contact us at snowconvert-support@snowflake.com

SSC-PRF-TS0001¶

Description¶

This warning appears when SnowConvert detects a Common Table Expression (CTE) but has not verified whether the CTE contains recursive operations in its query definition.

Snowflake SQL requires the RECURSIVE keyword for recursive Common Table Expressions (CTEs). Currently, SnowConvert does not automatically detect recursive queries to determine whether the RECURSIVE keyword should be included. This warning notifies you that you may need to manually add the RECURSIVE keyword for recursive CTEs.

Support for this validation may be added in future releases as requirements evolve.

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;
Copy

Generated 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;
Copy

Best Practices¶

  • The RECURSIVE keyword is optional and won’t affect your query results. However, it may influence how Snowflake allocates resources during execution. We recommend reviewing Snowflake’s CTE documentation and contacting us if you’d like automatic RECURSIVE keyword addition for compatible CTE queries.

  • For additional assistance, please email us at snowconvert-support@snowflake.com