OPEN { cursor_variable | :host_cursor_variable}FOR select_statement [ using_clause ] ;
Snowflake Scripting has no direct equivalence with cursor variables and the OPEN FOR statement, however, they can be emulated with different workarounds to get functional equivalence.
Sample Source Patterns
1. OPEN FOR statement with dynamic SQL inside a VARCHAR variable
IN -> Oracle_01.sql
CREATE OR REPLACE PROCEDURE procedure1AS query1 VARCHAR(200) :='SELECT 123 FROM dual'; cursor_var SYS_REFCURSOR;BEGINOPEN cursor_var FOR query1;CLOSE cursor_var;END;
OUT -> Oracle_01.sql
CREATE OR REPLACE PROCEDURE procedure1 ()RETURNS VARCHARLANGUAGE SQLCOMMENT='{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'EXECUTE AS CALLERAS$$DECLARE query1 VARCHAR(200) :='SELECT 123 FROM dual'; cursor_var_res RESULTSET;BEGIN !!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!! cursor_var_res := (EXECUTE IMMEDIATE :query1 ); LET cursor_var CURSORFOR cursor_var_res;OPEN cursor_var;CLOSE cursor_var;END;$$;
2. OPEN FOR statement with dynamic SQL inside a string literal.
IN -> Oracle_02.sql
CREATE OR REPLACE PROCEDURE procedure2AS cursor_var SYS_REFCURSOR;BEGINOPEN cursor_var FOR'SELECT 123 FROM dual';CLOSE cursor_var;END;
OUT -> Oracle_02.sql
CREATE OR REPLACE PROCEDURE procedure2 ()RETURNS VARCHARLANGUAGE SQLCOMMENT='{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'EXECUTE AS CALLERAS$$DECLARE cursor_var_res RESULTSET;BEGIN !!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!! cursor_var_res := (EXECUTE IMMEDIATE'SELECT 123 FROM dual' ); LET cursor_var CURSORFOR cursor_var_res;OPEN cursor_var;CLOSE cursor_var;END;$$;
CREATE OR REPLACE PROCEDURE procedure3 ()RETURNS VARCHARLANGUAGE SQLCOMMENT='{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'EXECUTE AS CALLERAS$$DECLARE cursor_var_res RESULTSET;BEGIN LET cursor_var CURSORFORSELECT123FROM dual;OPEN cursor_var;CLOSE cursor_var;END;$$;
4. Cursor Variable declared with REF CURSOR type
IN -> Oracle_04.sql
CREATE OR REPLACE PROCEDURE procedure4ASTYPE cursor_ref_type1 IS REF CURSOR; query1 VARCHAR(200) :='SELECT 123 FROM dual'; cursor_var cursor_ref_type1;BEGINOPEN cursor_var FOR query1;CLOSE cursor_var;END;
OUT -> Oracle_04.sql
CREATE OR REPLACE PROCEDURE procedure4 ()RETURNS VARCHARLANGUAGE SQLCOMMENT='{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'EXECUTE AS CALLERAS$$DECLARE-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL REF CURSOR TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!-- TYPE cursor_ref_type1 IS REF CURSOR; query1 VARCHAR(200) :='SELECT 123 FROM dual'; cursor_var_res RESULTSET;BEGIN !!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!! cursor_var_res := (EXECUTE IMMEDIATE :query1 ); LET cursor_var CURSORFOR cursor_var_res;OPEN cursor_var;CLOSE cursor_var;END;$$;
5. OPEN FOR statement with USING clause
IN -> Oracle_05.sql
CREATE OR REPLACE PROCEDURE procedure5AS query1 VARCHAR(200) :='SELECT col1 FROM cursortable1 WHERE col1 = :a'; column_filter INTEGER:=1; cursor_var SYS_REFCURSOR;BEGINOPEN cursor_var FOR query1 USING column_filter;CLOSE cursor_var;END;
OUT -> Oracle_05.sql
CREATE OR REPLACE PROCEDURE procedure5 ()RETURNS VARCHARLANGUAGE SQLCOMMENT='{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'EXECUTE AS CALLERAS$$DECLARE query1 VARCHAR(200) :='SELECT col1 FROM cursortable1WHERE col1 = ?'; column_filter INTEGER:=1; cursor_var_res RESULTSET;BEGIN !!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!! cursor_var_res := (EXECUTE IMMEDIATE :query1 USING ( column_filter) ); LET cursor_var CURSORFOR cursor_var_res;OPEN cursor_var;CLOSE cursor_var;END;$$;
Known Issues
No issues were found.
Related EWIs
SSC-EWI-0030: The statement below has usages of dynamic SQL.
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.