SnowConvert:PL/SQL to Snowflake Scripting¶
ASSIGNMENT STATEMENT¶
Description¶
The assignment statement sets the value of a data item to a valid value.
(Oracle PL/SQL Language Reference ASSIGNMENT Statement)
Note
Some parts in the output code are omitted for clarity reasons.
assignment_statement_target := expression ;
assignment_statement_target =
{ collection_variable [ ( index ) ]
| cursor_variable
| :host_cursor_variable
| object[.attribute]
| out_parameter
| placeholder
| record_variable[.field]
| scalar_variable
}
LET <variable_name> <type> { DEFAULT | := } <expression> ;
LET <variable_name> { DEFAULT | := } <expression> ;
Note
LET
keyword is not needed for assignment statements when the variable has been declared before. Check Snowflake Assignment documentation for more information.
Sample Source Patterns¶
1. Scalar Variables¶
Oracle¶
CREATE TABLE TASSIGN (
COL1 NUMBER,
COL2 NUMBER,
COL3 VARCHAR(20),
COL4 VARCHAR(20)
);
CREATE OR REPLACE PROCEDURE PSCALAR
AS
var1 NUMBER := 40;
var2 NUMBER := 22.50;
var3 VARCHAR(20);
var4 BOOLEAN;
var5 NUMBER;
BEGIN
var1 := 1;
var2 := 2.1;
var2 := var2 + var2;
var3 := 'Hello World';
var4 := true;
var4 := var1 > 500;
IF var4 THEN
var5 := 0;
ELSE
var5 := 1;
END IF;
INSERT INTO TASSIGN VALUES(var1, var2, var3, var5);
END;
CALL PSCALAR();
SELECT * FROM TASSIGN;
COL1|COL2|COL3 |COL4|
----+----+-----------+----+
1| 4.2|Hello World| 1|
Snowflake Scripting¶
CREATE OR REPLACE TABLE TASSIGN (
COL1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
COL2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
COL3 VARCHAR(20),
COL4 VARCHAR(20)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE PSCALAR ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
var1 NUMBER(38, 18) := 40;
var2 NUMBER(38, 18) := 22.50;
var3 VARCHAR(20);
var4 BOOLEAN;
var5 NUMBER(38, 18);
BEGIN
var1 := 1;
var2 := 2.1;
var2 := :var2 + :var2;
var3 := 'Hello World';
var4 := true;
var4 := :var1 > 500;
IF (:var4) THEN
var5 := 0;
ELSE
var5 := 1;
END IF;
INSERT INTO TASSIGN
VALUES(:var1, :var2, :var3, :var5);
END;
$$;
CALL PSCALAR();
SELECT * FROM
TASSIGN;
COL1 |COL2 |COL3 |COL4|
--------------------+--------------------+-----------+----+
1.000000000000000000|4.000000000000000000|Hello World|1 |
Warning
Transformation for some data types needs to be updated, it may cause different results. For example, NUMBER to NUMBER rounds the value and the decimal point is lost. There is already a work item for this issue.
2. Out Parameter Assignment¶
To get more information about how the output parameters are being converted, please go to the following article Output Parameters.
3. Not Supported Assignments¶
Oracle¶
CREATE OR REPLACE PROCEDURE pinvalid(out_parameter IN OUT NUMBER)
AS
record_variable employees%ROWTYPE;
TYPE cursor_type IS REF CURSOR;
cursor1 cursor_type;
cursor2 SYS_REFCURSOR;
TYPE collection_type IS TABLE OF NUMBER INDEX BY VARCHAR(64);
collection_variable collection_type;
BEGIN
--Record Example
record_variable.last_name := 'Ortiz';
--Cursor Example
cursor1 := cursor2;
--Collection
collection_variable('Test') := 5;
--Out Parameter
out_parameter := 123;
END;
Snowflake Scripting¶
--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "employees" **
CREATE OR REPLACE PROCEDURE pinvalid (out_parameter NUMBER(38, 18))
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
record_variable OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWTYPE DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL REF CURSOR TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE cursor_type IS REF CURSOR;
cursor1_res RESULTSET;
cursor2_res RESULTSET;
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE collection_type IS TABLE OF NUMBER INDEX BY VARCHAR(64);
collection_variable VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'collection_type' USAGE CHANGED TO VARIANT ***/!!!;
BEGIN
--Record Example
record_variable := OBJECT_INSERT(record_variable, 'LAST_NAME', 'Ortiz', true);
--Cursor Example
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0108 - THE FOLLOWING ASSIGNMENT STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
cursor1 := :cursor2;
--Collection
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0108 - THE FOLLOWING ASSIGNMENT STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
collection_variable('Test') := 5;
--Out Parameter
out_parameter := 123;
RETURN out_parameter;
END;
$$;
Known Issues¶
1. Several Unsupported Assignment Statements¶
Currently, transformation for cursor, collection, record, and user-defined type variables are not supported by Snow Scripting. Therefore assignment statements using these variables are commented and marked as not supported. Changing these variables to Snowflake semi-structured data types could help as a workaround in some scenarios.
CALL¶
Description¶
There are two types of call statements in Oracle:
1-CALL Statement:¶
Use the CALL
statement to execute a routine (a standalone procedure or function, or a procedure or function defined within a type or package) from within SQL. (Oracle SQL Language Reference CALL)
2-Call Specification:¶
A call specification declares a Java method or a C language subprogram so that it can be invoked from PL/SQL. (Oracle SQL Language Reference Call Specification)
The CALL Specification is not supported in snowflake scripting since this is part of the development libraries for C and JAVA, not a SQL statement, therefore this statement is not transformed.
Known Issues¶
No issues were found.
Related EWIs¶
No related EWIs.
CASE¶
Description¶
The CASE
statement chooses from a sequence of conditions and runs a corresponding statement. For more information regarding Oracle CASE, check here.
Note
Some parts in the output code are omitted for clarity reasons.
Simple case¶
[ <<label>> ] CASE case_operand
WHEN boolean_expression THEN statement ;
[ WHEN boolean_expression THEN statement ; ]...
[ ELSE statement [ statement ]... ;
END CASE [ label ] ;
CASE ( <expression_to_match> )
WHEN <expression> THEN
<statement>;
[ <statement>; ... ]
[ WHEN ... ]
[ ELSE
<statement>;
[ <statement>; ... ]
]
END [ CASE ] ;
Searched case¶
[ <<label>> ] CASE
WHEN boolean_expression THEN statement ;
[ WHEN boolean_expression THEN statement ; ]...
[ ELSE statement [ statement ]... ;
END CASE [ label ];
CASE
WHEN <boolean_expression> THEN
<statement>;
[ <statement>; ... ]
[ WHEN ... ]
[ ELSE
<statement>;
[ <statement>; ... ]
]
END [ CASE ] ;
Sample Source Patterns¶
Sample auxiliar table¶
CREATE TABLE case_table(col varchar(30));
CREATE OR REPLACE TABLE case_table (col varchar(30))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
Simple Case¶
Oracle¶
CREATE OR REPLACE PROCEDURE caseExample1 ( grade NUMBER )
IS
RESULT VARCHAR(20);
BEGIN
<<CASE1>>
CASE grade
WHEN 10 THEN RESULT:='Excellent';
WHEN 9 THEN RESULT:='Very Good';
WHEN 8 THEN RESULT:='Good';
WHEN 7 THEN RESULT:='Fair';
WHEN 6 THEN RESULT:='Poor';
ELSE RESULT:='No such grade';
END CASE CASE1;
INSERT INTO CASE_TABLE(COL) VALUES (RESULT);
END;
CALL caseExample1(6);
CALL caseExample1(4);
CALL caseExample1(10);
SELECT * FROM CASE_TABLE;
|COL |
|-------------|
|Poor |
|No such grade|
|Excellent |
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE caseExample1 (grade NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT VARCHAR(20);
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0094 - LABEL DECLARATION FOR A STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING <<CASE1>> ***/!!!
CASE :grade
WHEN 10 THEN
RESULT := 'Excellent';
WHEN 9 THEN
RESULT := 'Very Good';
WHEN 8 THEN
RESULT := 'Good';
WHEN 7 THEN
RESULT := 'Fair';
WHEN 6 THEN
RESULT := 'Poor';
ELSE
RESULT := 'No such grade';
END CASE;
INSERT INTO CASE_TABLE(COL) VALUES (:RESULT);
END;
$$;
CALL caseExample1(6);
CALL caseExample1(4);
CALL caseExample1(10);
--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "CASE_TABLE" **
SELECT * FROM
CASE_TABLE;
|COL |
|-------------|
|Poor |
|No such grade|
|Excellent |
Searched Case¶
Oracle¶
CREATE OR REPLACE PROCEDURE caseExample2 ( grade NUMBER )
IS
RESULT VARCHAR(20);
BEGIN
<<CASE1>>
CASE
WHEN grade = 10 THEN RESULT:='Excellent';
WHEN grade = 9 THEN RESULT:='Very Good';
WHEN grade = 8 THEN RESULT:='Good';
WHEN grade = 7 THEN RESULT:='Fair';
WHEN grade = 6 THEN RESULT:='Poor';
ELSE RESULT:='No such grade';
END CASE CASE1;
INSERT INTO CASE_TABLE(COL) VALUES (RESULT);
END;
CALL caseExample2(6);
CALL caseExample2(4);
CALL caseExample2(10);
SELECT * FROM CASE_TABLE;
|COL |
|-------------|
|Poor |
|No such grade|
|Excellent |
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE caseExample2 (grade NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT VARCHAR(20);
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0094 - LABEL DECLARATION FOR A STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING <<CASE1>> ***/!!!
CASE
WHEN :grade = 10 THEN
RESULT := 'Excellent';
WHEN :grade = 9 THEN
RESULT := 'Very Good';
WHEN :grade = 8 THEN
RESULT := 'Good';
WHEN :grade = 7 THEN
RESULT := 'Fair';
WHEN :grade = 6 THEN
RESULT := 'Poor';
ELSE
RESULT := 'No such grade';
END CASE;
INSERT INTO CASE_TABLE(COL) VALUES (:RESULT);
END;
$$;
CALL caseExample2(6);
CALL caseExample2(4);
CALL caseExample2(10);
--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "CASE_TABLE" **
SELECT * FROM
CASE_TABLE;
|COL |
|-------------|
|Poor |
|No such grade|
|Excellent |
Known issues¶
1. Labels are not supported in Snowflake Scripting CASE syntax¶
The labels are commented out or removed depending on their position.
Related EWIS¶
SSC-EWI-0094: Label declaration not supported.
SSC-FDM-0007: Element with missing dependencies.
COMPOUND STATEMENTS¶
Warning
This section is a work in progress, information may change in the future.
Note
Some parts in the output code are omitted for clarity reasons.
General description¶
The basic unit of a PL/SQL source program is the block, which groups related declarations and statements.
A PL/SQL block is defined by the keywords DECLARE, BEGIN, EXCEPTION, and END. These keywords divide the block into a declarative part, an executable part, and an exception-handling part. Only the executable part is required. (PL/SQL Anonymous Blocks)
The BEGIN...END
block in Oracle can have the following characteristics:
Be nested.
Contain the DECLARE statement for variables.
Group multiple SQL or PL/SQL statements.
Oracle syntax¶
[DECLARE <Variable declaration>]
BEGIN
<Executable statements>
[EXCEPTION <Exception handler>]
END
Snowflake syntax¶
BEGIN
<statement>;
[ <statement>; ... ]
[ EXCEPTION <exception_handler> ]
END;
Note
In Snowflake, a BEGIN/END block can be the top-level construct inside an anonymous block (Snowflake documentation).
Sample Source Patterns¶
1. IF-ELSE block¶
Review the following documentation about IF statements to learn more: SnowConvert IF statements translation and Snowflake IF statement documentation
Oracle¶
DECLARE
age NUMBER := 18;
BEGIN
IF age >= 18 THEN
DBMS_OUTPUT.PUT_LINE('You are an adult.');
ELSE
DBMS_OUTPUT.PUT_LINE('You are a minor.');
END IF;
END;
Statement processed.
You are an adult.
Snowflake¶
Warning
When calling a procedure or user-defined function (UDF), generating code is needed to support the equivalence as call_results
variable. In this case, is used to print the information.
Review the user-defined function (UDF) used here.
DECLARE
age NUMBER(38, 18) := 18;
call_results VARIANT;
BEGIN
IF (:age >= 18) THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('You are an adult.')
);
ELSE
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('You are a minor.')
);
END IF;
RETURN call_results;
END;
anonymous block
You are an adult.
2. CASE statement¶
For more information, review the following documentation: SnowConvert CASE statement documentation and Snowflake CASE documentation
Oracle¶
BEGIN
DECLARE
day_of_week NUMBER := 3;
BEGIN
CASE day_of_week
WHEN 1 THEN DBMS_OUTPUT.PUT_LINE('Sunday');
WHEN 2 THEN DBMS_OUTPUT.PUT_LINE('Monday');
WHEN 3 THEN DBMS_OUTPUT.PUT_LINE('Tuesday');
WHEN 4 THEN DBMS_OUTPUT.PUT_LINE('Wednesday');
WHEN 5 THEN DBMS_OUTPUT.PUT_LINE('Thursday');
WHEN 6 THEN DBMS_OUTPUT.PUT_LINE('Friday');
WHEN 7 THEN DBMS_OUTPUT.PUT_LINE('Saturday');
ELSE DBMS_OUTPUT.PUT_LINE('Invalid day');
END CASE;
END;
END;
Statement processed.
Tuesday
Snowflake¶
Warning
When calling a procedure or user-defined function (UDF), generating code is needed to support the equivalence as call_results
variable. In this case, is used to print the information.
Review the user-defined function (UDF) used here.
DECLARE
call_results VARIANT;
BEGIN
DECLARE
day_of_week NUMBER(38, 18) := 3;
BEGIN
CASE :day_of_week
WHEN 1 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Sunday')
);
WHEN 2 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Monday')
);
WHEN 3 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Tuesday')
);
WHEN 4 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Wednesday')
);
WHEN 5 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Thursday')
);
WHEN 6 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Friday')
);
WHEN 7 THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Saturday')
);
ELSE
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('Invalid day')
);
END CASE;
END;
RETURN call_results;
END;
anonymous block
Tuesday
3. LOOP statements¶
For more information review the following documentation: SnowConvert FOR LOOP and Snowflake LOOP documentation and FOR documentation.
Oracle¶
BEGIN
FOR i IN 1..10 LOOP
NULL;
END LOOP;
END;
Statement processed.
Snowflake¶
BEGIN
FOR i IN 1 TO 10 LOOP
NULL;
END LOOP;
END;
anonymous block
4. Procedure call and OUTPUT parameters¶
Anonymous block in Oracle may have calls to procedures. Furthermore, the following documentation may be useful: SnowConvert Procedure documentation.
The following example uses the OUT parameters, the information about the current transformation can be found here: SnowConvert OUTPUT Parameters
Oracle¶
-- Procedure declaration
CREATE OR REPLACE PROCEDURE calculate_sum(
p_num1 IN NUMBER,
p_num2 IN NUMBER,
p_result OUT NUMBER
)
IS
BEGIN
-- Calculate the sum of the two numbers
p_result := p_num1 + p_num2;
END;
/
-- Anonymous block with a procedure call
DECLARE
-- Declare variables to hold the input and output values
v_num1 NUMBER := 10;
v_num2 NUMBER := 20;
v_result NUMBER;
BEGIN
-- Call the procedure with the input values and get the result
calculate_sum(v_num1, v_num2, v_result);
-- Display the result
DBMS_OUTPUT.PUT_LINE('The sum of ' || v_num1 || ' and ' || v_num2 || ' is ' || v_result);
END;
/
Statement processed.
The sum of 10 and 20 is 30
Snowflake¶
-- Procedure declaration
CREATE OR REPLACE PROCEDURE calculate_sum (p_num1 NUMBER(38, 18), p_num2 NUMBER(38, 18), p_result NUMBER(38, 18)
)
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
-- Calculate the sum of the two numbers
p_result := :p_num1 + :p_num2;
RETURN p_result;
END;
$$;
-- Anonymous block with a procedure call
DECLARE
-- Declare variables to hold the input and output values
v_num1 NUMBER(38, 18) := 10;
v_num2 NUMBER(38, 18) := 20;
v_result NUMBER(38, 18);
call_results VARIANT;
BEGIN
call_results := (
CALL
-- Call the procedure with the input values and get the result
calculate_sum(:v_num1, :v_num2, :v_result)
);
v_result := :call_results;
-- Display the result
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF('The sum of ' || NVL(:v_num1 :: STRING, '') || ' and ' || NVL(:v_num2 :: STRING, '') || ' is ' || NVL(:v_result :: STRING, ''))
);
RETURN call_results;
END;
anonymous block
The sum of 10 and 20 is 30
5. Alter session¶
For more information, review the following documentation: Alter session documentation.
Notice that in Oracle, the block BEGIN...END
should use the EXECUTE IMMEDIATE
statement to run alter session
statements.
Oracle¶
DECLARE
lv_sql_txt VARCHAR2(200);
BEGIN
lv_sql_txt := 'ALTER SESSION SET nls_date_format = ''DD-MM-YYYY''';
EXECUTE IMMEDIATE lv_sql_txt;
END;
Statement processed.
Done
Snowflake¶
Warning
The following warning may be added in the future:
/*** MSC-WARNING - MSCEWI3058 - NLS_DATE_FORMAT SESSION PARAMETER DOES NOT ENFORCE THE INPUT FORMAT IN ORACLE ***/
DECLARE
lv_sql_txt VARCHAR(200);
BEGIN
lv_sql_txt := 'ALTER SESSION SET nls_date_format = ''DD-MM-YYYY''';
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!!!!RESOLVE EWI!!! /*** SSC-EWI-0027 - THE FOLLOWING STATEMENT USES A VARIABLE/LITERAL WITH AN INVALID QUERY AND IT WILL NOT BE EXECUTED ***/!!!
EXECUTE IMMEDIATE :lv_sql_txt;
END;
anonymous block
Done
6. Cursors¶
The following example displays the usage of a cursor
inside a BEGIN...END
block. Review the following documentation to learn more: Cursor documentation.
Oracle¶
CREATE TABLE employee (
ID_Number NUMBER,
emp_Name VARCHAR(200),
emp_Phone NUMBER
);
INSERT INTO employee VALUES (1, 'NameA NameZ', 1234567890);
INSERT INTO employee VALUES (2, 'NameB NameY', 1234567890);
DECLARE
var1 VARCHAR(20);
CURSOR cursor1 IS SELECT emp_Name FROM employee ORDER BY ID_Number;
BEGIN
OPEN cursor1;
FETCH cursor1 INTO var1;
CLOSE cursor1;
DBMS_OUTPUT.PUT_LINE(var1);
END;
Statement processed.
NameA NameZ
Snowflake¶
Warning
When calling a procedure or user-defined function (UDF), generating code is needed to support the equivalence as call_results
variable. In this case, is used to print the information.
Review the user-defined function (UDF) used here.
CREATE OR REPLACE TABLE employee (
ID_Number NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
emp_Name VARCHAR(200),
emp_Phone NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
INSERT INTO employee
VALUES (1, 'NameA NameZ', 1234567890);
INSERT INTO employee
VALUES (2, 'NameB NameY', 1234567890);
DECLARE
var1 VARCHAR(20);
cursor1 CURSOR
FOR
SELECT emp_Name FROM
employee
ORDER BY ID_Number;
call_results VARIANT;
BEGIN
OPEN cursor1;
FETCH cursor1 INTO
:var1;
CLOSE cursor1;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF(:var1)
);
RETURN call_results;
END;
anonymous block
NameA NameZ
7. Select statements¶
For more information review the following documentation: Select documentation.
Oracle¶
CREATE TABLE employee (
ID_Number NUMBER,
emp_Name VARCHAR(200),
emp_Phone NUMBER
);
INSERT INTO employee VALUES (1, 'NameA NameZ', 1234567890);
INSERT INTO employee VALUES (2, 'NameB NameY', 1234567890);
DECLARE
var_Result NUMBER;
BEGIN
SELECT COUNT(*) INTO var_Result FROM employee;
DBMS_OUTPUT.PUT_LINE(var_Result);
END;
Statement processed.
2
Snowflake¶
Warning
When calling a procedure or user-defined function (UDF), generating code is needed to support the equivalence as call_results
variable. In this case, is used to print the information.
Review the user-defined function (UDF) used here.
CREATE OR REPLACE TABLE employee (
ID_Number NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
emp_Name VARCHAR(200),
emp_Phone NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
INSERT INTO employee
VALUES (1, 'NameA NameZ', 1234567890);
INSERT INTO employee
VALUES (2, 'NameB NameY', 1234567890);
DECLARE
var_Result NUMBER(38, 18);
call_results VARIANT;
BEGIN
SELECT COUNT(*) INTO
:var_Result
FROM
employee;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF(:var_Result)
);
RETURN call_results;
END;
anonymous block
2
8. Join Statements¶
For more information review the following documentation: Joins documentation.
Oracle¶
CREATE TABLE t1 (col1 INTEGER);
CREATE TABLE t2 (col1 INTEGER);
INSERT INTO t1 (col1) VALUES (2);
INSERT INTO t1 (col1) VALUES (3);
INSERT INTO t1 (col1) VALUES (4);
INSERT INTO t2 (col1) VALUES (1);
INSERT INTO t2 (col1) VALUES (2);
INSERT INTO t2 (col1) VALUES (2);
INSERT INTO t2 (col1) VALUES (3);
DECLARE
total_price FLOAT;
CURSOR cursor1 IS SELECT t1.col1 as FirstTable, t2.col1 as SecondTable
FROM t1 INNER JOIN t2
ON t2.col1 = t1.col1
ORDER BY 1,2;
BEGIN
total_price := 0.0;
FOR rec IN cursor1 LOOP
total_price := total_price + rec.FirstTable;
END LOOP;
DBMS_OUTPUT.PUT_LINE(total_price);
END;
Statement processed.
7
Snowflake¶
Warning
When calling a procedure or user-defined function (UDF), generating code is needed to support the equivalence as call_results
variable. In this case, is used to print the information.
Review the user-defined function (UDF) used here.
CREATE OR REPLACE TABLE t1 (col1 INTEGER)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE TABLE t2 (col1 INTEGER)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
INSERT INTO t1(col1) VALUES (2);
INSERT INTO t1(col1) VALUES (3);
INSERT INTO t1(col1) VALUES (4);
INSERT INTO t2(col1) VALUES (1);
INSERT INTO t2(col1) VALUES (2);
INSERT INTO t2(col1) VALUES (2);
INSERT INTO t2(col1) VALUES (3);
DECLARE
total_price FLOAT;
cursor1 CURSOR
FOR
SELECT t1.col1 as FIRSTTABLE, t2.col1 as SECONDTABLE
FROM
t1
INNER JOIN
t2
ON t2.col1 = t1.col1
ORDER BY 1,2;
call_results VARIANT;
BEGIN
total_price := 0.0;
OPEN cursor1;
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR rec IN cursor1 DO
total_price :=
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '+' MAY NOT BEHAVE CORRECTLY BETWEEN AproxNumeric AND unknown ***/!!!
:total_price + rec.FIRSTTABLE;
END FOR;
CLOSE cursor1;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
call_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF(:total_price)
);
RETURN call_results;
END;
9. Exception handling¶
Oracle¶
DECLARE
v_result NUMBER;
BEGIN
v_result := 1 / 0;
EXCEPTION
WHEN ZERO_DIVIDE THEN
DBMS_OUTPUT.PUT_LINE( SQLERRM );
END;
Statement processed.
ORA-01476: divisor is equal to zero
Snowflake¶
Warning
ZERO_DIVIDE
exception in Snowflake is not supported.
DECLARE
v_result NUMBER(38, 18);
error_results VARIANT;
BEGIN
v_result := 1 / 0;
EXCEPTION
WHEN ZERO_DIVIDE THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
error_results := (
CALL DBMS_OUTPUT.PUT_LINE_UDF( SQLERRM )
);
RETURN error_results;
END;
anonymous block
Division by zero
Known issues¶
Unsupported GOTO statements in Oracle.
Exceptions that use GOTO statements may be affected too.
Cursor functionality may be adapted under current restrictions on translations.
Related EWIs¶
SSC-EWI-0027:The following statement uses a variable/literal with an invalid query and it will not be executed.
SSC-EWI-OR0036: Types resolution issues, the arithmetic operation may not behave correctly between string and date.
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-PRF-0004: This statement has usages of cursor for loop.
SSC-EWI-0030: The statement below has usages of dynamic SQL
CONTINUE¶
Description¶
The CONTINUE
statement exits the current iteration of a loop, either conditionally or unconditionally, and transfers control to the next iteration of either the current loop or an enclosing labeled loop.
(Oracle PL/SQL Language Reference CONTINUE Statement)
Note
Some parts in the output code are omitted for clarity reasons.
CONTINUE [ label ] [ WHEN boolean_expression ] ;
{ CONTINUE | ITERATE } [ <label> ] ;
Sample Source Patterns¶
1. Simple Continue¶
Code skips the INSERT
statement by using CONTINUE
.
This case is functionally equivalent.
Oracle
CREATE TABLE continue_testing_table_1 (iterator VARCHAR2(5));
CREATE OR REPLACE PROCEDURE continue_procedure_1
IS
I NUMBER := 0;
J NUMBER := 20;
BEGIN
WHILE I <= J LOOP
I := I + 1;
CONTINUE;
INSERT INTO continue_testing_table_1
VALUES (TO_CHAR(I));
END LOOP;
END;
CALL continue_procedure_1();
SELECT * FROM continue_testing_table_1;
ITERATOR|
--------+
Snowflake Scripting
CREATE OR REPLACE TABLE continue_testing_table_1 (iterator VARCHAR(5))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE continue_procedure_1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 0;
J NUMBER(38, 18) := 20;
BEGIN
WHILE (:I <= :J) LOOP
I := :I + 1;
CONTINUE;
INSERT INTO continue_testing_table_1
VALUES (TO_CHAR(:I));
END LOOP;
END;
$$;
CALL continue_procedure_1();
SELECT * FROM
continue_testing_table_1;
ITERATOR|
--------+
2. Continue with condition
Code skips inserting even numbers by using CONTINUE
.
Note
This case is not functionally equivalent, but, you can turn the condition into an IF
statement.
Oracle¶
CREATE TABLE continue_testing_table_2 (iterator VARCHAR2(5));
CREATE OR REPLACE PROCEDURE continue_procedure_2
IS
I NUMBER := 0;
J NUMBER := 20;
BEGIN
WHILE I <= J LOOP
I := I + 1;
CONTINUE WHEN MOD(I,2) = 0;
INSERT INTO continue_testing_table_2 VALUES(TO_CHAR(I));
END LOOP;
END;
CALL continue_procedure_2();
SELECT * FROM continue_testing_table_2;
ITERATOR|
--------+
1 |
3 |
5 |
7 |
9 |
11 |
13 |
15 |
17 |
19 |
21 |
Snowflake Scripting¶
CREATE OR REPLACE TABLE continue_testing_table_2 (iterator VARCHAR(5))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE continue_procedure_2 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 0;
J NUMBER(38, 18) := 20;
BEGIN
WHILE (:I <= :J) LOOP
I := :I + 1;
IF (MOD(:I,2) = 0) THEN
CONTINUE;
END IF;
INSERT INTO continue_testing_table_2
VALUES(TO_CHAR(:I));
END LOOP;
END;
$$;
CALL continue_procedure_2();
SELECT * FROM
continue_testing_table_2;
ITERATOR|
--------+
1 |
3 |
5 |
7 |
9 |
11 |
13 |
15 |
17 |
19 |
21 |
3. Continue with label and condition¶
Code skips line 19, and the inner loop is only executed once because the CONTINUE
is always jumping to the outer loop using the label.
This case is functionally equivalent applying the same process as the previous sample.
Note
Note that labels are going to be commented out.
Oracle¶
CREATE OR REPLACE PROCEDURE continue_procedure_3
IS
I NUMBER := 0;
J NUMBER := 10;
K NUMBER := 0;
BEGIN
<<out_loop>>
WHILE I <= J LOOP
I := I + 1;
INSERT INTO continue_testing_table_3 VALUES('I' || TO_CHAR(I));
<<in_loop>>
WHILE K <= J * 2 LOOP
K := K + 1;
CONTINUE out_loop WHEN K > J / 2;
INSERT INTO continue_testing_table_3 VALUES('K' || TO_CHAR(K));
END LOOP in_loop;
K := 0;
END LOOP out_loop;
END;
CALL continue_procedure_3();
SELECT * FROM continue_testing_table_3;
ITERATOR|
--------+
I1 |
K1 |
K2 |
K3 |
K4 |
K5 |
I2 |
I3 |
I4 |
I5 |
I6 |
I7 |
I8 |
I9 |
I10 |
I11 |
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE continue_procedure_3 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 0;
J NUMBER(38, 18) := 10;
K NUMBER(38, 18) := 0;
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0094 - LABEL DECLARATION FOR A STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING <<out_loop>> ***/!!!
WHILE (:I <= :J) LOOP
I := :I + 1;
INSERT INTO continue_testing_table_3
VALUES('I' || NVL(TO_CHAR(:I) :: STRING, ''));
!!!RESOLVE EWI!!! /*** SSC-EWI-0094 - LABEL DECLARATION FOR A STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING <<in_loop>> ***/!!!
WHILE (:K <= :J * 2) LOOP
K := :K + 1;
IF (:K > :J / 2) THEN
CONTINUE out_loop;
END IF;
INSERT INTO continue_testing_table_3
VALUES('K' || NVL(TO_CHAR(:K) :: STRING, ''));
END LOOP in_loop;
K := 0;
END LOOP out_loop;
END;
$$;
CALL continue_procedure_3();
SELECT * FROM
continue_testing_table_3;
ITERATOR|
--------+
I1 |
K1 |
K2 |
K3 |
K4 |
K5 |
I2 |
I3 |
I4 |
I5 |
I6 |
I7 |
I8 |
I9 |
I10 |
I11 |
Known Issues¶
No issues were found.
Related EWIs¶
SSC-EWI-0094: Label declaration not supported.
CREATE PROCEDURE¶
Description¶
Note
Some parts in the output code are omitted for clarity reasons.
A procedure is a group of PL/SQL statements that you can call by name. A call specification (sometimes called call spec) declares a Java method or a third-generation language (3GL) routine so that it can be called from SQL and PL/SQL. The call spec tells Oracle Database which Java method to invoke when a call is made. It also tells the database what type conversions to make for the arguments and return value. Oracle SQL Language Reference Create Procedure.
For more information regarding Oracle Create Procedure, check here.
CREATE [ OR REPLACE ] [ EDITIONABLE | NONEDITIONABLE ]
PROCEDURE
[ schema. ] procedure_name
[ ( parameter_declaration [, parameter_declaration ]... ) ] [ sharing_clause ]
[ ( default_collation_option | invoker_rights_clause | accessible_by_clause)... ]
{ IS | AS } { [ declare_section ]
BEGIN statement ...
[ EXCEPTION exception_handler [ exception_handler ]... ]
END [ name ] ;
|
{ java_declaration | c_declaration } } ;
For more information regarding Snowflake Create Procedure, check here.
CREATE [ OR REPLACE ] PROCEDURE <name> ( [ <arg_name> <arg_data_type> ] [ , ... ] )
RETURNS <result_data_type> [ NOT NULL ]
LANGUAGE SQL
[ { CALLED ON NULL INPUT | { RETURNS NULL ON NULL INPUT | STRICT } } ]
[ VOLATILE | IMMUTABLE ]
[ COMMENT = '<string_literal>' ]
[ EXECUTE AS { CALLER | OWNER } ]
AS '<procedure_definition>'
Sample Source Patterns¶
1. Basic Procedure¶
CREATE OR REPLACE PROCEDURE PROC1
IS
BEGIN
null;
END;
CREATE OR REPLACE PROCEDURE PROC1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
null;
END;
$$;
2. Procedure with Different Parameters¶
CREATE OR REPLACE PROCEDURE proc2
(
p1 OUT INTEGER,
p2 OUT INTEGER,
p3 INTEGER := 1,
p4 INTEGER DEFAULT 1
)
AS
BEGIN
p1 := 17;
p2 := 93;
END;
CREATE OR REPLACE PROCEDURE proc2
(p1 INTEGER, p2 INTEGER,
p3 INTEGER DEFAULT 1,
p4 INTEGER DEFAULT 1
)
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
p1 := 17;
p2 := 93;
RETURN OBJECT_CONSTRUCT('p1', :p1, 'p2', :p2);
END;
$$;
Output parameters¶
Snowflake does not allow output parameters in procedures, a way to simulate this behavior could be to declare a variable and return its value at the end of the procedure.
Parameters with default values¶
Snowflake does not allow setting default values for parameters in procedures, a way to simulate this behavior could be to declare a variable with the default value or overload the procedure.
3. Procedure with Additional Settings¶
CREATE OR REPLACE PROCEDURE proc3
DEFAULT COLLATION USING_NLS_COMP
AUTHID CURRENT_USER
AS
BEGIN
NULL;
END;
CREATE OR REPLACE PROCEDURE proc3 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "11/14/2024", "domain": "test" }}'
EXECUTE AS CALLER
AS
$$
BEGIN
NULL;
END;
$$;
4. Procedure with Basic Statements¶
CREATE OR REPLACE PROCEDURE proc4
(
param1 NUMBER
)
IS
localVar1 NUMBER;
countRows NUMBER;
tempSql VARCHAR(100);
tempResult NUMBER;
CURSOR MyCursor IS SELECT COL1 FROM Table1;
BEGIN
localVar1 := param1;
countRows := 0;
tempSql := 'SELECT COUNT(*) FROM Table1 WHERE COL1 =' || localVar1;
FOR myCursorItem IN MyCursor
LOOP
localVar1 := myCursorItem.Col1;
countRows := countRows + 1;
END LOOP;
INSERT INTO Table2 VALUES(countRows, 'ForCursor: Total Row count is: ' || countRows);
countRows := 0;
OPEN MyCursor;
LOOP
FETCH MyCursor INTO tempResult;
EXIT WHEN MyCursor%NOTFOUND;
countRows := countRows + 1;
END LOOP;
CLOSE MyCursor;
INSERT INTO Table2 VALUES(countRows, 'LOOP: Total Row count is: ' || countRows);
EXECUTE IMMEDIATE tempSql INTO tempResult;
IF tempResult > 0 THEN
INSERT INTO Table2 (COL1, COL2) VALUES(tempResult, 'Hi, found value:' || localVar1 || ' in Table1 -- There are ' || tempResult || ' rows');
COMMIT;
END IF;
END proc3;
CREATE OR REPLACE PROCEDURE proc4
(param1 NUMBER(38, 18)
)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
localVar1 NUMBER(38, 18);
countRows NUMBER(38, 18);
tempSql VARCHAR(100);
tempResult NUMBER(38, 18);
MyCursor CURSOR
FOR
SELECT COL1 FROM
Table1;
BEGIN
localVar1 := :param1;
countRows := 0;
tempSql := 'SELECT COUNT(*) FROM
Table1
WHERE COL1 =' || NVL(:localVar1 :: STRING, '');
OPEN MyCursor;
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR myCursorItem IN MyCursor DO
localVar1 := myCursorItem.Col1;
countRows := :countRows + 1;
END FOR;
CLOSE MyCursor;
INSERT INTO Table2
VALUES(:countRows, 'ForCursor: Total Row count is: ' || NVL(:countRows :: STRING, ''));
countRows := 0;
OPEN MyCursor;
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH MyCursor INTO
:tempResult;
IF (tempResult IS NULL) THEN
EXIT;
END IF;
countRows := :countRows + 1;
END LOOP;
CLOSE MyCursor;
INSERT INTO Table2
SELECT
:countRows,
'LOOP: Total Row count is: ' || NVL(:countRows :: STRING, '');
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE :tempSql
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'EXECUTE IMMEDIATE RETURNING CLAUSE' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
INTO tempResult;
IF (:tempResult > 0) THEN
INSERT INTO Table2(COL1, COL2)
SELECT
:tempResult,
'Hi, found value:' || NVL(:localVar1 :: STRING, '') || ' in Table1 -- There are ' || NVL(:tempResult :: STRING, '') || ' rows';
--** SSC-FDM-OR0012 - COMMIT REQUIRES THE APPROPRIATE SETUP TO WORK AS INTENDED **
COMMIT;
END IF;
END;
$$;
5. Procedure with empty RETURN
statements¶
In Oracle procedures you can have empty RETURN
statements to finish the execution of a procedure. In Snowflake Scripting procedures can have RETURN
statements but they must have a value. By default all empty RETURN
statements are converted with a NULL
value.
-- Procedure with empty return
CREATE OR REPLACE PROCEDURE MY_PROC
IS
BEGIN
NULL;
RETURN;
END;
-- Procedure with empty return
CREATE OR REPLACE PROCEDURE MY_PROC ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
NULL;
RETURN NULL;
END;
$$;
RETURN
statements in procedures with output parameters¶
In procedures with output parameters, instead of a NULL
value an OBJECT_CONSTRUCT
will be used in the empty RETURN
statements to simulate the output parameters in Snowflake Scripting.
CREATE OR REPLACE PROCEDURE PROC_WITH_OUTPUT_PARAMETERS (
param1 OUT NUMBER,
param2 OUT NUMBER,
param3 NUMBER
)
IS
BEGIN
IF param3 > 0 THEN
param1 := 2;
param2 := 1000;
RETURN;
END IF;
param1 := 5;
param2 := 3000;
END;
CREATE OR REPLACE PROCEDURE PROC_WITH_OUTPUT_PARAMETERS (param1 NUMBER(38, 18), param2 NUMBER(38, 18), param3 NUMBER(38, 18)
)
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
IF (:param3 > 0) THEN
param1 := 2;
param2 := 1000;
RETURN OBJECT_CONSTRUCT('param1', :param1, 'param2', :param2);
END IF;
param1 := 5;
param2 := 3000;
RETURN OBJECT_CONSTRUCT('param1', :param1, 'param2', :param2);
END;
$$;
6. Procedure with DEFAULT parameters¶
DEFAULT parameters allow named parameters to be initialized with default values if no value is passed.
CREATE OR REPLACE PROCEDURE TEST(
X IN VARCHAR DEFAULT 'P',
Y IN VARCHAR DEFAULT 'Q'
)
AS
varX VARCHAR(32767) := NVL(X, 'P');
varY NUMBER := NVL(Y, 1);
BEGIN
NULL;
END TEST;
BEGIN
TEST(Y => 'Y');
END;
CREATE OR REPLACE PROCEDURE TEST (
X VARCHAR DEFAULT 'P',
Y VARCHAR DEFAULT 'Q'
)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
varX VARCHAR(32767) := NVL(:X, 'P');
varY NUMBER(38, 18) := NVL(:Y, 1 :: STRING);
BEGIN
NULL;
END;
$$;
DECLARE
call_results VARIANT;
BEGIN
CALL
TEST(Y => 'Y');
RETURN call_results;
END;
Known Issues¶
1. Unsupported OUT parameters¶
Snowflake procedures do not have a native option for output parameters.
2. Unsupported Oracle additional settings¶
The following Oracle settings and clauses are not supported by Snowflake procedures:
sharing_clause
default_collation_option
invoker_rights_clause
accessible_by_clause
java_declaration
c_declaration
Related EWIS¶
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting
SSC-EWI-OR0097: Procedures properties are not supported in Snowflake procedures.
SSC-FDM-OR0012: COMMIT and ROLLBACK statements require adequate setup to perform as intended.
SSC-PRF-0003: Fetch inside a loop is considered a complex pattern, this could degrade Snowflake performance.
SSC-PRF-0004: This statement has usages of cursor for loop.
SSC-EWI-0030: The statement below has usages of dynamic SQL
DECLARE¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
Oracle DECLARE statement is an optional part of the PL/SQL block statement. It allows the creation of variables, constants, procedures declarations, and definitions, functions declarations, and definitions, exceptions, cursors, types, and many other statements. For more information regarding Oracle DECLARE, check here.
declare_section body
declare_section::= { item_list_1 [ item_list_2 ] | item_list_2 }
item_list_1::=
{ type_definition
| cursor_declaration
| item_declaration
| function_declaration
| procedure_declaration
}
...
item_list_2::=
{ cursor_declaration
| cursor_definition
| function_declaration
| function_definition
| procedure_declaration
| procedure_definition
}
...
item_declaration::=
{ collection_variable_decl
| constant_declaration
| cursor_variable_declaration
| exception_declaration
| record_variable_declaration
| variable_declaration
}
body::= BEGIN statement ...
[ EXCEPTION exception_handler [ exception_handler ]... ] END [ name ] ;
[ DECLARE
{ <variable_declaration> | <cursor_declaration> | <exception_declaration> | <resultset_declaration> }
[, { <variable_declaration> | <cursor_declaration> | <exception_declaration> | <resultset_declaration> } ... ]
]
BEGIN
<statement>;
[ <statement>; ... ]
[ EXCEPTION <exception_handler> ]
END [ <label> ] ;
Sample Source Patterns¶
Variable declaration¶
variable_declaration::=
variable datatype [ [ NOT NULL] {:= | DEFAULT} expression ] ;
<variable_name> <type>;
<variable_name> DEFAULT <expression> ;
<variable_name> <type> DEFAULT <expression> ;
Oracle¶
CREATE OR REPLACE PROCEDURE var_decl_proc
IS
var1 NUMBER;
var2 NUMBER := 1;
var3 NUMBER NOT NULL := 1;
var4 NUMBER DEFAULT 1;
var5 NUMBER NOT NULL DEFAULT 1;
BEGIN
NULL;
END;
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE var_decl_proc ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
var1 NUMBER(38, 18);
var2 NUMBER(38, 18) := 1;
var3 NUMBER(38, 18) := 1 /*** SSC-FDM-OR0025 - NOT NULL CONSTRAINT IS NOT SUPPORTED BY SNOWFLAKE ***/;
var4 NUMBER(38, 18) DEFAULT 1;
var5 NUMBER(38, 18) DEFAULT 1 /*** SSC-FDM-OR0025 - NOT NULL CONSTRAINT IS NOT SUPPORTED BY SNOWFLAKE ***/;
BEGIN
NULL;
END;
$$;
Constant declaration¶
Warning
Constants are not supported in Snowflake Scripting, however, they are being transformed to variables to simulate the behavior.
constant_declaration::=
constant CONSTANT datatype [NOT NULL] { := | DEFAULT } expression ;
<variable_name> <type>;
<variable_name> DEFAULT <expression> ;
<variable_name> <type> DEFAULT <expression> ;
Oracle¶
CREATE OR REPLACE PROCEDURE const_decl_proc
IS
my_const1 CONSTANT NUMBER := 40;
my_const2 CONSTANT NUMBER NOT NULL := 40;
my_const2 CONSTANT NUMBER DEFAULT 40;
my_const2 CONSTANT NUMBER NOT NULL DEFAULT 40;
BEGIN
NULL;
END;
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE const_decl_proc ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
--** SSC-FDM-0016 - CONSTANTS ARE NOT SUPPORTED BY SNOWFLAKE SCRIPTING. IT WAS TRANSFORMED TO A VARIABLE **
my_const1 NUMBER(38, 18) := 40;
--** SSC-FDM-0016 - CONSTANTS ARE NOT SUPPORTED BY SNOWFLAKE SCRIPTING. IT WAS TRANSFORMED TO A VARIABLE **
--** SSC-FDM-OR0025 - NOT NULL CONSTRAINT IS NOT SUPPORTED BY SNOWFLAKE **
my_const2 NUMBER(38, 18) := 40;
--** SSC-FDM-0016 - CONSTANTS ARE NOT SUPPORTED BY SNOWFLAKE SCRIPTING. IT WAS TRANSFORMED TO A VARIABLE **
my_const2 NUMBER(38, 18) DEFAULT 40;
--** SSC-FDM-0016 - CONSTANTS ARE NOT SUPPORTED BY SNOWFLAKE SCRIPTING. IT WAS TRANSFORMED TO A VARIABLE **
--** SSC-FDM-OR0025 - NOT NULL CONSTRAINT IS NOT SUPPORTED BY SNOWFLAKE **
my_const2 NUMBER(38, 18) DEFAULT 40;
BEGIN
NULL;
END;
$$;
Cursor declaration¶
cursor_declaration::= CURSOR cursor
[( cursor_parameter_dec [, cursor_parameter_dec ]... )]
RETURN rowtype;
cursor_parameter_dec::= parameter [IN] datatype [ { := | DEFAULT } expression ]
rowtype::=
{ {db_table_or_view | cursor | cursor_variable}%ROWTYPE
| record%TYPE
| record_type
}
<cursor_name> CURSOR [ ( <argument> [, <argument> ... ] ) ]
FOR <query> ;
The Oracle cursor declaration is not required so it might be commented out on the output code. The cursor definition will be used instead of and it will be converted to the Snowflake Scripting cursor declaration. Please go to the CURSOR section to get more information about cursor definition.
Exception declaration
The exception declaration sometimes could be followed by the exception initialization, the current transformation takes both and merge them into the Snowflake Scripting exception declaration. The original PRAGMA
EXCEPTION_INIT
will be commented out.
exception_declaration::= exception EXCEPTION;
PRAGMA EXCEPTION_INIT ( exception, error_code ) ;
<exception_name> EXCEPTION [ ( <exception_number> , '<exception_message>' ) ] ;
Oracle
CREATE OR REPLACE PROCEDURE procedure_exception
IS
my_exception EXCEPTION;
my_exception2 EXCEPTION;
PRAGMA EXCEPTION_INIT ( my_exception2, -20100 );
my_exception3 EXCEPTION;
PRAGMA EXCEPTION_INIT ( my_exception3, -19000 );
BEGIN
NULL;
END;
Snowflake Scripting
CREATE OR REPLACE PROCEDURE procedure_exception ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
my_exception EXCEPTION;
my_exception2 EXCEPTION (-20100, '');
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0051 - PRAGMA EXCEPTION_INIT IS NOT SUPPORTED ***/!!!
PRAGMA EXCEPTION_INIT ( my_exception2, -20100 );
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0099 - EXCEPTION CODE NUMBER EXCEEDS SNOWFLAKE SCRIPTING LIMITS ***/!!!
my_exception3 EXCEPTION;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0051 - PRAGMA EXCEPTION_INIT IS NOT SUPPORTED ***/!!!
PRAGMA EXCEPTION_INIT ( my_exception3, -19000 );
BEGIN
NULL;
END;
$$;
Not supported cases
The next Oracle declaration statements are not supported by the Snowflake Scripting declaration block:
Cursor variable declaration.
Collection variable declaration.
Record variable declaration.
Type definition (all its variants).
Function declaration and definition.
Procedure declaration and definition.
Known issues
1. The variable declarations with NOT NULL constraints are not supported by Snow Scripting.
The creation of variables with NOT NULL
constraint throws an error in Snow Scripting.
2. The cursor declaration has no equivalent to Snowflake Scripting.
The Oracle cursor declaration is useless so it might be commented out in the output code. The cursor definition will be used instead and it will be converted to the Snowflake Scripting cursor declaration.
3. The exception code exceeds Snowflake Scripting limits.
Oracle exception code is being removed when it exceeds the Snowflake Scripting code limits. The exception code must be an integer between -20000 and -20999.
3. The not supported cases.
There are some Oracle declaration statements that are not supported by the Snowflake Scripting declaration block, so it might be commented out and a warning will be added.
Related EWIS
SSC-EWI-OR0051: PRAGMA EXCEPTION_INIT is not supported.
SSC-EWI-OR0099: The exception code exceeds the Snowflake Scripting limit.
SSC-FDM-0016: Constants are not supported by Snowflake Scripting. It was transformed into a variable.
SSC-FDM-OR0025: Not Null constraint is not supported in Snowflake Procedures.
DEFAULT PARAMETERS
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
A default parameter is a parameter that has a value in case an argument is not passed in the procedure or function call. Since Snowflake doesn’t support default parameters, SnowConvert inserts the default value in the procedure or function call.
In the declaration, the DEFAULT VALUE clause of the parameter is removed. Both syntaxes, the :=
symbol and the DEFAULT
clause, are supported.
Sample Source Patterns¶
Sample auxiliary code¶
CREATE TABLE TABLE1(COL1 NUMBER, COL2 NUMBER);
CREATE TABLE TABLE2(COL1 NUMBER, COL2 NUMBER, COL2 NUMBER);0016
CREATE OR REPLACE TABLE TABLE1 (COL1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
COL2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE TABLE TABLE2 (COL1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
COL2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
COL2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
Default parameter declaration¶
Oracle¶
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_PARAMS1 (
param1 NUMBER,
param2 NUMBER default TO_NUMBER(1)
)
AS
BEGIN
INSERT INTO TABLE1 (COL1, COL2)
VALUES(param1, param2);
END;
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_PARAMS2 (
param1 NUMBER default 1,
param2 NUMBER default 2
)
AS
BEGIN
INSERT INTO TABLE1 (COL1, COL2)
VALUES(param1, param2);
END;
CREATE OR REPLACE PROCEDURE PROCEDURE_WITH_DEAFAULT_PARAMS3 (
param1 NUMBER DEFAULT 100,
param2 NUMBER,
param3 NUMBER DEFAULT 1000
)
IS
BEGIN
INSERT INTO TABLE2(COL1, COL2, COL3)
VALUES (param1, param2, param3);
END;
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_PARAMS1 (param1 NUMBER(38, 18),
param2 NUMBER(38, 18) DEFAULT TO_NUMBER(1)
)
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 TABLE1(COL1, COL2)
VALUES(:param1, :param2);
END;
$$;
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_PARAMS2 (
param1 NUMBER(38, 18) DEFAULT 1,
param2 NUMBER(38, 18) DEFAULT 2
)
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 TABLE1(COL1, COL2)
VALUES(:param1, :param2);
END;
$$;
CREATE OR REPLACE PROCEDURE PROCEDURE_WITH_DEAFAULT_PARAMS3 (
param1 NUMBER(38, 18) DEFAULT 100, param2 NUMBER(38, 18),
param3 NUMBER(38, 18) DEFAULT 1000
)
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 TABLE2(COL1, COL2, COL3)
VALUES (:param1, :param2, :param3);
END;
$$;
Calling procedures with default parameters¶
Oracle¶
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_CALLS
AS
BEGIN
PROC_WITH_DEFAULT_PARAMS1(10, 15);
PROC_WITH_DEFAULT_PARAMS1(10);
PROC_WITH_DEFAULT_PARAMS2(10, 15);
PROC_WITH_DEFAULT_PARAMS2(10);
PROC_WITH_DEFAULT_PARAMS2();
END;
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_CALLS ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CALL
PROC_WITH_DEFAULT_PARAMS1(10, 15);
CALL
PROC_WITH_DEFAULT_PARAMS1(10);
CALL
PROC_WITH_DEFAULT_PARAMS2(10, 15);
CALL
PROC_WITH_DEFAULT_PARAMS2(10);
CALL
PROC_WITH_DEFAULT_PARAMS2();
END;
$$;
In order to check that the functionality is being emulated correctly the following query is going to execute the procedure and a SELECT
from the table mentioned before.
Oracle¶
CALL PROC_WITH_DEFAULT_CALLS();
SELECT * FROM TABLE1;
|COL1|COL2|
|----|----|
|10 |15 |
|10 |1 |
|10 |15 |
|10 |2 |
|1 |2 |
Snowflake Scripting¶
CALL PROC_WITH_DEFAULT_CALLS();
SELECT * FROM TABLE1;
|COL1|COL2|
|----|----|
|10 |15 |
|10 |1 |
|10 |15 |
|10 |2 |
|1 |2 |
Calling procedures with named arguments and default parameters¶
Oracle¶
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_CALLS2
AS
BEGIN
PROCEDURE_WITH_DEAFAULT_PARAMS3(10, 20, 30);
PROCEDURE_WITH_DEAFAULT_PARAMS3(param1 => 10, param2 => 20, param3 => 30);
PROCEDURE_WITH_DEAFAULT_PARAMS3(param3 => 10, param1 => 20, param2 => 30);
PROCEDURE_WITH_DEAFAULT_PARAMS3(param3 => 10, param2 => 30);
PROCEDURE_WITH_DEAFAULT_PARAMS3(param2 => 10, param3 => 30);
PROCEDURE_WITH_DEAFAULT_PARAMS3(param2 => 10);
END;
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE PROC_WITH_DEFAULT_CALLS2 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CALL
PROCEDURE_WITH_DEAFAULT_PARAMS3(10, 20, 30);
CALL
PROCEDURE_WITH_DEAFAULT_PARAMS3(10, 20, 30);
CALL
PROCEDURE_WITH_DEAFAULT_PARAMS3(10, 20, 30);
CALL
PROCEDURE_WITH_DEAFAULT_PARAMS3(10, 30);
CALL
PROCEDURE_WITH_DEAFAULT_PARAMS3(10, 30);
CALL
PROCEDURE_WITH_DEAFAULT_PARAMS3(10);
END;
$$;
In order to check that the functionality is being emulated correctly the following query is going to execute the procedure and a SELECT
from the table mentioned before.
Oracle¶
CALL PROC_WITH_DEFAULT_CALLS2();
SELECT * FROM TABLE2;
|COL1|COL2|COL3|
|----|----|----|
|10 |20 |30 |
|10 |20 |30 |
|20 |30 |10 |
|100 |30 |10 |
|100 |10 |30 |
|100 |10 |1000|
Snowflake Scripting¶
CALL PROC_WITH_DEFAULT_CALLS2();
SELECT * FROM TABLE2;
|COL1|COL2|COL3|
|----|----|----|
|10 |20 |30 |
|10 |20 |30 |
|20 |30 |10 |
|100 |30 |10 |
|100 |10 |30 |
|100 |10 |1000|
Known Issues¶
1. No issues found
Related EWIs¶
No related EWIs.
EXECUTE IMMEDIATE¶
Description¶
The EXECUTE
IMMEDIATE
statement builds and runs a dynamic SQL statement in a single operation.
Native dynamic SQL uses the EXECUTE
IMMEDIATE
statement to process most dynamic SQL statements. (Oracle PL/SQL Language Reference EXECUTE IMMEDIATE Statement)
EXECUTE IMMEDIATE <dynamic statement> [<additional clause> , ...];
dynamic statement::= { '<string literal>' | <variable> }
additional clauses::=
{ <into clause> [<using clause>]
| <bulk collect into clause> [<using clause>]
| <using clause> [<dynamic return clause>]
| <dynamic return clasue> }
Snowflake Scripting has support for this statement, albeit with some functional differences. For more information on the Snowflake counterpart, please visit Snowflake’s EXECUTE IMMEDIATE documentation.
EXECUTE IMMEDIATE <dynamic statement> ;
dynamic statement::= {'<string literal>' | <variable> | $<session variable>}
Sample Source Patterns¶
The next samples will create a table, and attempt to drop the table using Execute Immediate.
Using a hard-coded string¶
Oracle¶
CREATE TABLE immediate_dropped_table(
col1 INTEGER
);
CREATE OR REPLACE PROCEDURE dropping_procedure
AS BEGIN
EXECUTE IMMEDIATE 'DROP TABLE immediate_dropped_table PURGE';
END;
CALL dropping_procedure();
SELECT * FROM immediate_dropped_table;
Snowflake Scripting¶
CREATE OR REPLACE TABLE immediate_dropped_table (
col1 INTEGER
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE dropping_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE 'DROP TABLE immediate_dropped_table';
END;
$$;
CALL dropping_procedure();
SELECT * FROM
immediate_dropped_table;
Storing the string in a variable¶
Oracle¶
CREATE TABLE immediate_dropped_table(
col1 INTEGER
);
CREATE OR REPLACE PROCEDURE dropping_procedure
AS
BEGIN
DECLARE
statement_variable VARCHAR2(500) := 'DROP TABLE immediate_dropped_table PURGE';
BEGIN
EXECUTE IMMEDIATE statement_variable;
END;
END;
CALL dropping_procedure();
SELECT * FROM immediate_dropped_table;
Snowflake Scripting¶
CREATE OR REPLACE TABLE immediate_dropped_table (
col1 INTEGER
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE dropping_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
DECLARE
statement_variable VARCHAR(500) := 'DROP TABLE immediate_dropped_table';
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE :statement_variable;
END;
END;
$$;
CALL dropping_procedure();
SELECT * FROM
immediate_dropped_table;
Concatenation for parameters in dynamic statement¶
Oracle¶
CREATE TABLE immediate_dropped_table(
col1 INTEGER
);
CREATE OR REPLACE PROCEDURE dropping_procedure(param1 VARCHAR2)
AS
BEGIN
DECLARE
statement_variable VARCHAR2(500) := 'DROP TABLE ' || param1 || ' PURGE';
BEGIN
EXECUTE IMMEDIATE statement_variable;
END;
END;
CALL dropping_procedure();
SELECT * FROM immediate_dropped_table;
Snowflake Scripting¶
CREATE OR REPLACE TABLE immediate_dropped_table (
col1 INTEGER
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE dropping_procedure (param1 VARCHAR)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
DECLARE
statement_variable VARCHAR(500) := 'DROP TABLE ' || NVL(:param1 :: STRING, '');
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE :statement_variable;
END;
END;
$$;
CALL dropping_procedure();
SELECT * FROM
immediate_dropped_table;
USING Clause transformation¶
Oracle¶
CREATE TABLE immediate_inserted_table(COL1 INTEGER);
CREATE OR REPLACE PROCEDURE inserting_procedure_using(param1 INTEGER)
AS
BEGIN
EXECUTE IMMEDIATE 'INSERT INTO immediate_inserted_table VALUES (:1)' USING param1;
END;
CALL inserting_procedure_using(1);
SELECT * FROM immediate_inserted_table;
COL1|
----+
1|
Snowflake Scripting¶
Note
Please note parenthesis are required for parameters in the USING Clause in Snowflake Scripting.
CREATE OR REPLACE TABLE immediate_inserted_table (COL1 INTEGER)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE inserting_procedure_using (param1 INTEGER)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE 'INSERT INTO immediate_inserted_table
VALUES (?)' USING ( param1);
END;
$$;
CALL inserting_procedure_using(1);
SELECT * FROM
immediate_inserted_table;
COL1|
----+
1|
Known Issues¶
1. Immediate Execution results cannot be stored in variables.¶
SnowScripting does not support INTO nor BULK COLLECT INTO clauses. For this reason, results will need to be passed through other means.
2. Numeric Placeholders¶
Numeric Names for placeholders are currently not being recognized by SnowConvert, but there is a work item to fix this issue.
3. Argument Expressions are not supported by Snowflake Scripting¶
In Oracle it is possible to use Expressions as Arguments for the Using Clause; however, this is not supported by Snowflake Scripting, and they are commented out.
4. Dynamic SQL Execution queries may be marked incorrectly as non-runnable.¶
In some scenarios there an execute statement may be commented regardless of being safe or non-safe to run so please take this into account:
Oracle¶
CREATE OR REPLACE PROCEDURE inserting_procedure_variable_execute_concatenation_parameter(param1 INTEGER)
IS
query VARCHAR2(500) := 'INSERT INTO immediate_inserted_table VALUES (';
BEGIN
EXECUTE IMMEDIATE query || param1 || ')';
END;
Snowflake Scripting¶
Note
Please note parenthesis are required for parameters in the USING Clause in Snowflake Scripting.
CREATE OR REPLACE PROCEDURE inserting_procedure_variable_execute_concatenation_parameter (param1 INTEGER)
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
query VARCHAR(500) := 'INSERT INTO immediate_inserted_table VALUES (';
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
!!!RESOLVE EWI!!! /*** SSC-EWI-0027 - THE FOLLOWING STATEMENT USES A VARIABLE/LITERAL WITH AN INVALID QUERY AND IT WILL NOT BE EXECUTED ***/!!!
EXECUTE IMMEDIATE NVL(:query :: STRING, '') || NVL(:param1 :: STRING, '') || ')';
END;
$$;
Related EWIs¶
SSC-EWI-0027: Variable with invalid query.
SSC-EWI-0030: The statement below has usages of dynamic SQL.
EXIT¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The EXIT
statement exits the current iteration of a loop, either conditionally or unconditionally, and transfers control to the end of either the current loop or an enclosing labeled loop.
(Oracle PL/SQL Language Reference EXIT Statement)
EXIT [ label ] [ WHEN boolean_expression ] ;
{ BREAK | EXIT } [ <label> ] ;
Sample Source Patterns¶
Note
Note that you can change EXIT
with BREAK
and everything will work the same.
1. Simple Exit¶
Code skips the INSERT
statement by using EXIT
.
This case is functionally equivalent.
Oracle
CREATE TABLE exit_testing_table_1 (
iterator VARCHAR2(5)
);
CREATE OR REPLACE PROCEDURE exit_procedure_1
IS
I NUMBER := 0;
J NUMBER := 20;
BEGIN
WHILE I <= J LOOP
I := I + 1;
EXIT;
INSERT INTO exit_testing_table_1 VALUES(TO_CHAR(I));
END LOOP;
END;
CALL exit_procedure_1();
SELECT * FROM exit_testing_table_1;
ITERATOR|
--------+
Snowflake Scripting
CREATE OR REPLACE TABLE exit_testing_table_1 (
iterator VARCHAR(5)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE exit_procedure_1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 0;
J NUMBER(38, 18) := 20;
BEGIN
WHILE (:I <= :J) LOOP
I := :I + 1;
EXIT;
INSERT INTO exit_testing_table_1
VALUES(TO_CHAR(:I));
END LOOP;
END;
$$;
CALL exit_procedure_1();
SELECT * FROM
exit_testing_table_1;
ITERATOR|
--------+
2. Exit with condition
Code exits the loop when the iterator is greater than 5.
This case is functionally equivalent by turning the condition into an IF
statement.
Oracle¶
CREATE TABLE exit_testing_table_2 (
iterator VARCHAR2(5)
);
CREATE OR REPLACE PROCEDURE exit_procedure_2
IS
I NUMBER := 0;
J NUMBER := 20;
BEGIN
WHILE I <= J LOOP
EXIT WHEN I > 5;
I := I + 1;
INSERT INTO exit_testing_table_2 VALUES(TO_CHAR(I));
END LOOP;
END;
CALL exit_procedure_2();
SELECT * FROM exit_testing_table_2;
ITERATOR|
--------+
1 |
2 |
3 |
4 |
5 |
6 |
Snowflake Scripting¶
CREATE OR REPLACE TABLE exit_testing_table_2 (
iterator VARCHAR(5)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE exit_procedure_2 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 0;
J NUMBER(38, 18) := 20;
BEGIN
WHILE (:I <= :J) LOOP
IF (:I > 5) THEN
EXIT;
END IF;
I := :I + 1;
INSERT INTO exit_testing_table_2
VALUES(TO_CHAR(:I));
END LOOP;
END;
$$;
CALL exit_procedure_2();
SELECT * FROM
exit_testing_table_2;
ITERATOR|
--------+
1 |
2 |
3 |
4 |
5 |
6 |
3. Exit with label and condition¶
Code breaks both loops by using the EXIT
statement pointing to the outer loop.
This case is functionally equivalent applying the same process as the previous sample.
Note
Note that labels are going to be commented out.
Oracle¶
CREATE TABLE exit_testing_table_3 (
iterator VARCHAR2(5)
);
CREATE OR REPLACE PROCEDURE exit_procedure_3
IS
I NUMBER := 0;
J NUMBER := 10;
K NUMBER := 0;
BEGIN
<<out_loop>>
WHILE I <= J LOOP
I := I + 1;
INSERT INTO exit_testing_table_3 VALUES('I' || TO_CHAR(I));
<<in_loop>>
WHILE K <= J * 2 LOOP
K := K + 1;
EXIT out_loop WHEN K > J / 2;
INSERT INTO exit_testing_table_3 VALUES('K' || TO_CHAR(K));
END LOOP in_loop;
K := 0;
END LOOP out_loop;
END;
CALL exit_procedure_3();
SELECT * FROM exit_testing_table_3;
ITERATOR|
--------+
I1 |
K1 |
K2 |
K3 |
K4 |
K5 |
Snowflake Scripting¶
CREATE OR REPLACE TABLE exit_testing_table_3 (
iterator VARCHAR(5)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE exit_procedure_3 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 0;
J NUMBER(38, 18) := 10;
K NUMBER(38, 18) := 0;
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0094 - LABEL DECLARATION FOR A STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING <<out_loop>> ***/!!!
WHILE (:I <= :J) LOOP
I := :I + 1;
INSERT INTO exit_testing_table_3
VALUES('I' || NVL(TO_CHAR(:I) :: STRING, ''));
!!!RESOLVE EWI!!! /*** SSC-EWI-0094 - LABEL DECLARATION FOR A STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING <<in_loop>> ***/!!!
WHILE (:K <= :J * 2) LOOP
K := :K + 1;
IF (:K > :J / 2) THEN
EXIT out_loop;
END IF;
INSERT INTO exit_testing_table_3
VALUES('K' || NVL(TO_CHAR(:K) :: STRING, ''));
END LOOP in_loop;
K := 0;
END LOOP out_loop;
END;
$$;
CALL exit_procedure_3();
SELECT * FROM
exit_testing_table_3;
ITERATOR|
--------+
I1 |
K1 |
K2 |
K3 |
K4 |
K5 |
Known Issues¶
No issues were found.
Related EWIs¶
SSC-EWI-0094: Label declaration not supported.
EXPRESSIONS¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The following table has a summary of how to transform the different Oracle Expression kinds into Snow Scripting.
Syntax |
Conversion status |
Notes |
---|---|---|
Partial |
||
Partial |
||
Partial |
||
Partial |
||
Full |
N/A |
|
Full |
N/A |
|
Not Translated |
Snowflake does not have a native equivalent for Oracle collections. See Collections and Records. |
|
Not Translated |
Snowflake does not have a native equivalent for Oracle record types. See Collections and Records. |
Partially supported common scenarios¶
Oracle Constants¶
For more information, check the Oracle Constant declaration section.
Oracle¶
CREATE TABLE EXPRESSIONS_TABLE(col VARCHAR(30));
CREATE OR REPLACE PROCEDURE EXPRESSIONS_SAMPLE
IS
RESULT VARCHAR(50);
CONST CONSTANT VARCHAR(20) := 'CONSTANT TEXT';
BEGIN
-- CONSTANT EXPRESSIONS
RESULT := CONST;
INSERT INTO EXPRESSIONS_TABLE(COL) VALUES (RESULT);
END;
CALL EXPRESSIONS_SAMPLE();
SELECT * FROM EXPRESSIONS_TABLE;
|COL |
|-------------|
|CONSTANT TEXT|
Snowflake¶
CREATE OR REPLACE TABLE EXPRESSIONS_TABLE (col VARCHAR(30))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE EXPRESSIONS_SAMPLE ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT VARCHAR(50);
--** SSC-FDM-0016 - CONSTANTS ARE NOT SUPPORTED BY SNOWFLAKE SCRIPTING. IT WAS TRANSFORMED TO A VARIABLE **
CONST VARCHAR(20) := 'CONSTANT TEXT';
BEGIN
-- CONSTANT EXPRESSIONS
RESULT := :CONST;
INSERT INTO EXPRESSIONS_TABLE(COL) VALUES (:RESULT);
END;
$$;
CALL EXPRESSIONS_SAMPLE();
SELECT * FROM
EXPRESSIONS_TABLE;
|COL |
|-------------|
|CONSTANT TEXT|
Not supported numeric expressions¶
Oracle¶
CREATE TABLE NUMERIC_EXPRESSIONS_TABLE(col number);
CREATE OR REPLACE PROCEDURE NUMERIC_EXPRESSIONS
IS
RESULT NUMBER;
CURSOR C1 IS SELECT * FROM NUMERIC_EXPRESSIONS_TABLE;
TYPE NUMERIC_TABLE IS TABLE OF NUMBER(10);
COLLECTION NUMERIC_TABLE;
BEGIN
-- CURSOR EXPRESSIONS
OPEN C1;
RESULT := C1%ROWCOUNT;
CLOSE C1;
INSERT INTO NUMERIC_EXPRESSIONS_TABLE(COL) VALUES (RESULT);
-- ** OPERATOR
RESULT := 10 ** 2;
INSERT INTO NUMERIC_EXPRESSIONS_TABLE(COL) VALUES (RESULT);
-- COLLECTION EXPRESSIONS
COLLECTION := NUMERIC_TABLE(1, 2, 3, 4, 5, 6);
RESULT := COLLECTION.COUNT + COLLECTION.FIRST;
INSERT INTO NUMERIC_EXPRESSIONS_TABLE(COL) VALUES (RESULT);
-- IMPLICIT CURSOR EXPRESSIONS
UPDATE NUMERIC_EXPRESSIONS_TABLE SET COL = COL + 4;
RESULT := SQL%ROWCOUNT;
INSERT INTO NUMERIC_EXPRESSIONS_TABLE(COL) VALUES (RESULT);
END;
CALL NUMERIC_EXPRESSIONS();
SELECT * FROM NUMERIC_EXPRESSIONS_TABLE;
|COL|
|---|
|4 |
|104|
|11 |
|3 |
Not supported boolean expressions¶
Oracle¶
--Aux function to convert BOOLEAN to VARCHAR
CREATE OR REPLACE FUNCTION convert_bool(p1 in BOOLEAN)
RETURN VARCHAR
AS
var1 VARCHAR(20) := 'FALSE';
BEGIN
IF p1 THEN
var1 := 'TRUE';
END IF;
RETURN var1;
END;
--Table
CREATE TABLE t_boolean_table
(
conditional_predicate VARCHAR(20),
collection_variable VARCHAR(20),
sql_variable VARCHAR(20)
)
--Main Procedure
CREATE OR REPLACE PROCEDURE p_boolean_limitations
AS
TYPE varray_example IS VARRAY(4) OF VARCHAR(15);
colection_example varray_example := varray_example('John', 'Mary', 'Alberto', 'Juanita');
collection_variable BOOLEAN;
conditional_predicate BOOLEAN;
sql_variable BOOLEAN;
--Result variables
col1 VARCHAR(20);
col2 VARCHAR(20);
col3 VARCHAR(20);
BEGIN
--Conditional predicate
conditional_predicate := INSERTING;
--Collection.EXISTS(index)
collection_variable := colection_example.EXISTS(2);
--Cursor FOUND / NOTFOUND / ISOPEN
sql_variable:= SQL%FOUND OR SQL%NOTFOUND OR SQL%ISOPEN;
--Convert BOOLEAN to VARCHAR to insert
col1 := convert_bool(conditional_predicate);
col2 := convert_bool(collection_variable);
col3 := convert_bool(sql_variable);
INSERT INTO t_boolean_table VALUES (col1, col2, col3);
END;
CALL p_boolean_limitations();
SELECT * FROM t_boolean_table;
Related EWIs.¶
SSC-FDM-0016: Constants are not supported by Snowflake Scripting. It was transformed to a variable.
FOR LOOP¶
Description¶
With each iteration of the FOR
LOOP
statement, its statements run, its index is either incremented or decremented, and control returns to the top of the loop. (Oracle PL/SQL Language Reference FOR LOOP Statement).
FOR
pls_identifier [ MUTABLE | IMMUTABLE ] [ constrained_type ]
[ , iterand_decl ]
IN
[ REVERSE ] iteration_control pred_clause_seq
[, qual_iteration_ctl]...
LOOP
statement...
END LOOP [ label ] ;
FOR <counter_variable> IN [ REVERSE ] <start> TO <end> { DO | LOOP }
statement;
[ statement; ... ]
END { FOR | LOOP } [ <label> ] ;
Snowflake Scripting supports FOR LOOP
that loops a specified number of times. The upper and lower bounds must be INTEGER
. Check more information in the Snowflake Scripting documentation.
Oracle FOR LOOP
behavior can also be modified by using the statements:
Sample Source Patterns¶
1. FOR LOOP¶
This case is functionally equivalent.
CREATE OR REPLACE PROCEDURE P1
AS
BEGIN
FOR i IN 1..10
LOOP
NULL;
END LOOP;
FOR i IN VAR1..VAR2
LOOP
NULL;
END LOOP;
FOR i IN REVERSE 1+2..10+5
LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE P1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
FOR i IN 1 TO 10 LOOP
NULL;
END LOOP;
FOR i IN VAR1 TO VAR2 LOOP
NULL;
END LOOP;
FOR i IN REVERSE 1+2 TO 10+5 LOOP
NULL;
END LOOP;
END;
$$;
2. FOR LOOP with additional clauses
CREATE OR REPLACE PROCEDURE P2
AS
BEGIN
FOR i IN 1..10 WHILE i <= 5 LOOP
NULL;
END LOOP;
FOR i IN 5..15 BY 5 LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE P2 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0101 - FOR LOOP WITH "WHILE" CLAUSE IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
FOR i IN 1 TO 10 LOOP
NULL;
END LOOP;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0101 - FOR LOOP WITH "BY" CLAUSE IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
FOR i IN 5 TO 15 LOOP
NULL;
END LOOP;
END;
$$;
3. FOR LOOP with multiple conditions
CREATE OR REPLACE PROCEDURE P3
AS
BEGIN
FOR i IN REVERSE 1..3,
REVERSE i+5..i+7
LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE P3 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0100 - FOR LOOP WITH MULTIPLE CONDITIONS IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
FOR i IN REVERSE 1 TO 3 LOOP
NULL;
END LOOP;
END;
$$;
4. FOR LOOP with unsupported format
CREATE OR REPLACE PROCEDURE P3
AS
TYPE values_aat IS TABLE OF PLS_INTEGER INDEX BY PLS_INTEGER;
l_employee_values values_aat;
BEGIN
FOR power IN REPEAT power*2 WHILE power <= 64 LOOP
NULL;
END LOOP;
FOR i IN VALUES OF l_employee_values LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE P3 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE values_aat IS TABLE OF PLS_INTEGER INDEX BY PLS_INTEGER;
l_employee_values VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'values_aat' USAGE CHANGED TO VARIANT ***/!!!;
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0103 - FOR LOOP FORMAT IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!!!!RESOLVE EWI!!! /*** SSC-EWI-OR0101 - FOR LOOP WITH "WHILE" CLAUSE IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
FOR power IN REPEAT power*2 WHILE power <= 64 LOOP
NULL;
END LOOP;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0103 - FOR LOOP FORMAT IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
FOR i IN VALUES OF :l_employee_values LOOP
NULL;
END LOOP;
END;
$$;
Warning
Transformation for custom types is currently not supported for Snowflake Scripting.
Known Issues¶
1. For With Multiple Conditions¶
Oracle allows multiple conditions in a single FOR LOOP
however, Snowflake Scripting only allows one condition per FOR LOOP
. Only the first condition is migrated and the others are ignored during transformation. Check SSC-FDM-OR0022.
FOR i IN REVERSE 1..3,
REVERSE i+5..i+7
LOOP
NULL;
END LOOP;
--** SSC-FDM-OR0022 - FOR LOOP WITH MULTIPLE CONDITIONS IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING **
FOR i IN REVERSE 1 TO 3 LOOP
NULL;
END LOOP;
2. Mutable vs Inmutable Counter Variable
Oracle allows modifying the value of the FOR LOOP
variable inside the loop. The current documentation includes this functionality but Snowflake recommends avoiding this. Modifying the value of this variable may not behave correctly in Snowflake Scripting.
3. Integer vs Float number for Upper or Lower Bound
Snowflake Scripting only allows an INTEGER
or an expression that evaluates to an INTEGER
as a bound for the FOR LOOP
condition. Floating numbers will be rounded up or down and alter the original bound. Check SSC-EWI-OR0102.
4. Oracle Unsupported Clauses
Oracle allows additional clauses to the FOR LOOP
condition. Like the BY clause for a stepped increment in the condition. And the WHILE and WHEN clause for boolean expressions. These additional clauses are not supported in Snowflake Scripting and are ignored during transformation. Check SSC-EWI-OR0101.
FOR i IN 5..15 BY 5 LOOP
NULL;
END LOOP;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0101 - FOR LOOP WITH "BY" CLAUSE IS CURRENTLY NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
FOR i IN 5 TO 15 LOOP
NULL;
END LOOP;
5. Unsupported Formats
Oracle allows different types of conditions for a FOR LOOP
. It supports boolean expressions, collections, records… However, Snowflake scripting only supports FOR LOOP
with defined integers as bounds. All other formats are marked as not supported and require additional manual effort to be transformed. Check SSC-EWI-OR0103.
Related EWIs¶
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-OR0100: For Loop With Multiple Conditions Is Currently Not Supported By Snowflake Scripting. Only First Condition Is Used.
SSC-EWI-OR0101: Specific For Loop Clause Is Currently Not Supported By Snowflake Scripting.
SSC-EWI-OR0103: For Loop Format Is Currently Not Supported By Snowflake Scripting.
FORALL¶
Description¶
The FORALL
statement runs one DML statement multiple times, with different values in the VALUES
and WHERE
clauses. (Oracle PL/SQL Language Reference FORALL Statement).
FORALL index IN bounds_clause [ SAVE ] [ EXCEPTIONS ] dml_statement ;
Warning
Snowflake Scripting has no direct equivalence with the FORALL
statement, however can be emulated with different workarounds to get functional equivalence.
Sample Source Patterns¶
Setup Data¶
Oracle¶
CREATE TABLE table1 (
column1 NUMBER,
column2 NUMBER
);
INSERT INTO table1 (column1, column2) VALUES (1, 2);
INSERT INTO table1 (column1, column2) VALUES (2, 3);
INSERT INTO table1 (column1, column2) VALUES (3, 4);
INSERT INTO table1 (column1, column2) VALUES (4, 5);
INSERT INTO table1 (column1, column2) VALUES (5, 6);
CREATE TABLE table2 (
column1 NUMBER,
column2 NUMBER
);
INSERT INTO table2 (column1, column2) VALUES (1, 2);
CREATE TABLE error_table (
ORA_ERR_NUMBER$ NUMBER,
ORA_ERR_MESG$ VARCHAR2(2000),
ORA_ERR_ROWID$ ROWID,
ORA_ERR_OPTYP$ VARCHAR2(2),
ORA_ERR_TAG$ VARCHAR2(2000)
);
--departments
CREATE TABLE parent_table(
Id INT PRIMARY KEY,
Name VARCHAR2(10)
);
INSERT INTO parent_table VALUES (10, 'IT');
INSERT INTO parent_table VALUES (20, 'HR');
INSERT INTO parent_table VALUES (30, 'INFRA');
--employees
CREATE TABLE source_table(
Id INT PRIMARY KEY,
Name VARCHAR2(20) NOT NULL,
DepartmentID INT REFERENCES parent_table(Id)
);
INSERT INTO source_table VALUES (101, 'Anurag111111111', 10);
INSERT INTO source_table VALUES (102, 'Pranaya11111111', 20);
INSERT INTO source_table VALUES (103, 'Hina11111111111', 30);
--a copy of source
CREATE TABLE target_table(
Id INT PRIMARY KEY,
Name VARCHAR2(10) NOT NULL,
DepartmentID INT REFERENCES parent_table(Id)
);
INSERT INTO target_table VALUES (101, 'Anurag', 10);
Snowflake¶
CREATE OR REPLACE TABLE table1 (
column1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
column2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO table1(column1, column2) VALUES (1, 2);
INSERT INTO table1(column1, column2) VALUES (2, 3);
INSERT INTO table1(column1, column2) VALUES (3, 4);
INSERT INTO table1(column1, column2) VALUES (4, 5);
INSERT INTO table1(column1, column2) VALUES (5, 6);
CREATE OR REPLACE TABLE table2 (
column1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
column2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO table2(column1, column2) VALUES (1, 2);
CREATE OR REPLACE TABLE error_table (
"ORA_ERR_NUMBER$" NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
"ORA_ERR_MESG$" VARCHAR(2000),
"ORA_ERR_ROWID$" VARCHAR(18) !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWID DATA TYPE CONVERTED TO VARCHAR ***/!!!,
"ORA_ERR_OPTYP$" VARCHAR(2),
"ORA_ERR_TAG$" VARCHAR(2000)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
--departments
CREATE OR REPLACE TABLE parent_table (
Id INT PRIMARY KEY,
Name VARCHAR(10)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO parent_table
VALUES (10, 'IT');
INSERT INTO parent_table
VALUES (20, 'HR');
INSERT INTO parent_table
VALUES (30, 'INFRA');
--employees
CREATE OR REPLACE TABLE source_table (
Id INT PRIMARY KEY,
Name VARCHAR(20) NOT NULL,
DepartmentID INT REFERENCES parent_table (Id)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO source_table
VALUES (101, 'Anurag111111111', 10);
INSERT INTO source_table
VALUES (102, 'Pranaya11111111', 20);
INSERT INTO source_table
VALUES (103, 'Hina11111111111', 30);
--a copy of source
CREATE OR REPLACE TABLE target_table (
Id INT PRIMARY KEY,
Name VARCHAR(10) NOT NULL,
DepartmentID INT REFERENCES parent_table (Id)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO target_table
VALUES (101, 'Anurag', 10);
1. FORALL With Collection of Records¶
Oracle
The three cases below have the same transformation to Snowflake Scripting and are functionally equivalent.
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS SELECT * FROM table1;
TYPE tableType IS TABLE OF cursorVariable%ROWTYPE;
tableVariable tableType;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO tableVariable LIMIT 100;
EXIT WHEN tableVariable.COUNT = 0;
FORALL forIndex IN 1..tableVariable.COUNT
INSERT INTO table2 (column1, column2)
VALUES (tableVariable(forIndex).column1, tableVariable(forIndex).column2);
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2(column1, column2)
(
SELECT
column1,
column2
FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
Note
The EWIs SSC-PRF-0001 and SSC-PRF-0003 are added in every FETCH BULK COLLECT occurrence into FORALL statement.
2. FORALL With INSERT INTO¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
* FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
3. FORALL With Multiple Fetched Collections¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
column1Collection dbms_sql.NUMBER_table;
column2Collection dbms_sql.NUMBER_table;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO column1Collection, column2Collection limit 20;
EXIT WHEN column1Collection.COUNT = 0;
FORALL forIndex IN 1..column1Collection.COUNT
INSERT INTO table2 VALUES (
column1Collection(forIndex),
column2Collection(forIndex)
);
END LOOP;
CLOSE cursorVariable;
END;
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
column1Collection dbms_sql.NUMBER_table;
column2Collection dbms_sql.NUMBER_table;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO column1Collection, column2Collection limit 2;
EXIT WHEN column1Collection.COUNT = 0;
FORALL forIndex IN 1..column1Collection.COUNT
UPDATE table2 SET column2 = column2Collection(forIndex)
WHERE column1 = column1Collection(forIndex);
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
1| 2|
COLUMN1| COLUMN2|
--------+--------+
1| 2|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
$1,
$2
FROM
table1
);
END;
$$;
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
UPDATE table2
SET column2 = column1Collection.$2
FROM
(
SELECT
* FROM
table1) AS column1Collection
WHERE
column1 = column1Collection.$1;
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
4. FORALL With Record of Collections¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE recordType IS RECORD(
column1Collection dbms_sql.NUMBER_table,
column2Collection dbms_sql.NUMBER_table
);
columnRecord recordType;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO columnRecord.column1Collection, columnRecord.column2Collection limit 20;
FORALL forIndex IN 1..columnRecord.column1Collection.COUNT
INSERT INTO table2 VALUES (
columnRecord.column1Collection(forIndex),
columnRecord.column2Collection(forIndex)
);
EXIT WHEN cursorVariable%NOTFOUND;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
$1,
$2
FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
5. FORALL With Dynamic SQL¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
cursorVariable SYS_REFCURSOR;
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
query VARCHAR(200) := 'SELECT * FROM table1';
BEGIN
OPEN cursorVariable FOR query;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
query VARCHAR(200) := 'SELECT * FROM
table1';
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE 'CREATE OR REPLACE TEMPORARY TABLE query AS ' || :query;
INSERT INTO table2
(
SELECT
*
FROM
query
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
6. FORALL With Literal SQL¶
Oracle¶
CREATE OR REPLACE PROCEDURE SampleProcedure
IS
TYPE TabRecType IS RECORD (
column1 NUMBER,
column2 NUMBER
);
TYPE tabType IS TABLE OF TabRecType;
cursorRef SYS_REFCURSOR;
tab tabType;
BEGIN
OPEN cursorRef FOR 'SELECT src.column1, src.column2 FROM ' || 'table1' || ' src';
LOOP
BEGIN
FETCH cursorRef BULK COLLECT INTO tab LIMIT 1000;
FORALL i IN 1..tab.COUNT
INSERT INTO table2 (column1, column2)
VALUES (tab(i).column1, tab(i).column2);
EXIT WHEN cursorRef%NOTFOUND;
END;
END LOOP;
CLOSE cursorRef;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE SampleProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
EXECUTE IMMEDIATE 'CREATE OR REPLACE TEMPORARY TABLE cursorRef_TEMP_TABLE AS ' || 'SELECT src.column1, src.column2 FROM ' || 'table1' || ' src';
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2(column1, column2)
(
SELECT
*
FROM
cursorRef_TEMP_TABLE
);
END;
$$;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
7. FORALL With Parametrized Cursors¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
intVariable INTEGER := 7;
CURSOR cursorVariable(param1 INTEGER, param2 INTEGER default 5) IS
SELECT * FROM table1
WHERE
column2 = intVariable OR
column1 BETWEEN param1 AND param2;
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable(1);
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 20;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
intVariable INTEGER := 7;
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
* FROM
table1
WHERE
column2 = :intVariable
OR
column1 BETWEEN 1 AND 5
);
END;
$$;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
8. FORALL Without LOOPS¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
SELECT * BULK COLLECT INTO collectionVariable FROM table1;
FORALL forIndex IN 1..collectionVariable.COUNT
INSERT INTO table2 VALUES (
collectionVariable (forIndex).column1,
collectionVariable (forIndex).column2
);
collectionVariable.DELETE;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
column1,
column2
FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
9. FORALL With UPDATE Statements¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
UPDATE table2 SET column1 = '54321' WHERE column2 = collectionVariable(forIndex).column2;
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
UPDATE table2
SET column1 = '54321'
FROM
(
SELECT
* FROM
table1) AS collectionVariable
WHERE
column2 = collectionVariable.column2;
END;
$$;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
10. FORALL With DELETE Statements¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
DELETE FROM table2 WHERE column2 = collectionVariable(forIndex).column2;
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
no data found
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
DELETE FROM
table2
USING (
SELECT
* FROM
table1) collectionVariable
WHERE
table2.column2 = collectionVariable.column2;
END;
$$;
Query produced no results
11. FORALL With PACKAGE References¶
Oracle¶
CREATE OR REPLACE PACKAGE MyPackage AS
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
END;
/
CREATE OR REPLACE PROCEDURE InsertIntoPackage(param integer) IS
BEGIN
SELECT
param,
param BULK COLLECT INTO MyPackage.collectionVariable
FROM
DUAL;
END;
/
CREATE OR REPLACE PROCEDURE InsertUsingPackage IS
BEGIN
FORALL forIndex IN MyPackage.collectionVariable.FIRST..MyPackage.collectionVariable.LAST
INSERT INTO table2 VALUES MyPackage.collectionVariable(forIndex);
MyPackage.collectionVariable.DELETE;
END;
/
DECLARE
param_value INTEGER := 10;
BEGIN
InsertIntoPackage(param_value);
InsertUsingPackage;
END;
select * from table2;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
10| 10|
Snowflake¶
CREATE SCHEMA IF NOT EXISTS MyPackage
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0049 - PACKAGE TYPE DEFINITIONS in stateful package MyPackage are not supported yet ***/!!!
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
CREATE OR REPLACE TEMPORARY TABLE MYPACKAGE_COLLECTIONVARIABLE (
);
CREATE OR REPLACE PROCEDURE InsertIntoPackage (param integer)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
DELETE FROM
MYPACKAGE_COLLECTIONVARIABLE;
INSERT INTO MYPACKAGE_COLLECTIONVARIABLE
(
SELECT
:param,
:param
FROM
DUAL
);
END;
$$;
CREATE OR REPLACE PROCEDURE InsertUsingPackage ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
*
FROM
MYPACKAGE_COLLECTIONVARIABLE
);
END;
$$;
DECLARE
param_value INTEGER := 10;
call_results VARIANT;
BEGIN
CALL
InsertIntoPackage(:param_value);
CALL
InsertUsingPackage();
RETURN call_results;
END;
select * from
table2;
COLUMN1| COLUMN2|
---------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
10.000000000000000000| 10.000000000000000000|
Warning
The transformation above only works if the variable defined in the package is a record of collections.
12. FORALL With MERGE Statements¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
MERGE INTO table2 tgt
USING (
SELECT
collectionVariable(forIndex).column1 column1,
collectionVariable(forIndex).column2 column2
FROM DUAL
) src
ON (tgt.column1 = src.column1)
WHEN MATCHED THEN
UPDATE SET
tgt.column2 = src.column2 * 2
WHEN NOT MATCHED THEN
INSERT (column1, column2)
VALUES (src.column1, src.column2);
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 4|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
MERGE INTO table2 tgt
USING (
SELECT
collectionVariable.column1 column1,
collectionVariable.column2 column2
FROM
(
SELECT
* FROM
table1
) collectionVariable
) src
ON (tgt.column1 = src.column1)
WHEN MATCHED THEN
UPDATE SET
tgt.column2 = src.column2 * 2
WHEN NOT MATCHED THEN
INSERT (column1, column2)
VALUES (src.column1, src.column2);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
1.000000000000000000| 4.000000000000000000|
Warning
The transformation above only works if the SELECT
statement inside the MERGE
is selecting from DUAL
table.
13. Default FORALL transformation¶
Note
You might also be interested in Bulk Cursor Helpers.
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS SELECT * FROM table1;
TYPE columnsRecordType IS RECORD (column1 dbms_sql.NUMBER_table, column2 dbms_sql.NUMBER_table);
recordVariable columnsRecordType;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
col1 dbms_sql.NUMBER_table;
col2 dbms_sql.NUMBER_table;
BEGIN
OPEN cursorVariable;
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 (column1, column2)
VALUES (collectionVariable(forIndex).column1, collectionVariable(forIndex).column2);
FETCH cursorVariable BULK COLLECT INTO col1, col2 limit 2;
FORALL forIndex IN col1.FIRST..col1.LAST
INSERT INTO table2 (column1, column2)
VALUES (col1(forIndex), col2(forIndex));
LOOP
FETCH cursorVariable BULK COLLECT INTO recordVariable limit 2;
EXIT WHEN recordVariable.column1.COUNT = 0;
FORALL forIndex IN recordVariable.column1.FIRST..recordVariable.column1.LAST
INSERT INTO table2 (column1, column2)
VALUES (recordVariable.column1(forIndex), recordVariable.column2(forIndex));
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursorVariable OBJECT := INIT_CURSOR_UDF('cursorVariable', ' SELECT * FROM
table1');
!!!RESOLVE EWI!!! /*** SSC-EWI-0056 - CUSTOM TYPES ARE NOT SUPPORTED IN SNOWFLAKE BUT REFERENCES TO THIS CUSTOM TYPE WERE CHANGED TO OBJECT ***/!!!
TYPE columnsRecordType IS RECORD (column1 dbms_sql.NUMBER_table, column2 dbms_sql.NUMBER_table);
recordVariable OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - columnsRecordType DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'collectionTypeDefinition' USAGE CHANGED TO VARIANT ***/!!!;
col1 VARIANT /*** SSC-FDM-0015 - REFERENCED CUSTOM TYPE 'dbms_sql.NUMBER_table' IN QUERY NOT FOUND, USAGES MAY BE AFFECTED ***/;
col2 VARIANT /*** SSC-FDM-0015 - REFERENCED CUSTOM TYPE 'dbms_sql.NUMBER_table' IN QUERY NOT FOUND, USAGES MAY BE AFFECTED ***/;
FORALL INTEGER;
BEGIN
cursorVariable := (
CALL OPEN_BULK_CURSOR_UDF(:cursorVariable)
);
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
cursorVariable := (
CALL FETCH_BULK_COLLECTION_RECORDS_UDF(:cursorVariable, 2)
);
collectionVariable := :cursorVariable:RESULT;
FORALL := ARRAY_SIZE(:collectionVariable);
INSERT INTO table2(column1, column2)
(
SELECT
:collectionVariable[forIndex]:column1,
: collectionVariable[forIndex]:column2
FROM
(
SELECT
seq4() AS forIndex
FROM
TABLE(GENERATOR(ROWCOUNT => :FORALL))
)
);
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
cursorVariable := (
CALL FETCH_BULK_COLLECTIONS_UDF(:cursorVariable, 2)
);
col1 := :cursorVariable:RESULT[0];
col2 := :cursorVariable:RESULT[1];
FORALL := ARRAY_SIZE(:col1);
INSERT INTO table2(column1, column2)
(
SELECT
:col1[forIndex],
: col2[forIndex]
FROM
(
SELECT
seq4() AS forIndex
FROM
TABLE(GENERATOR(ROWCOUNT => :FORALL))
)
);
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
cursorVariable := (
CALL FETCH_BULK_RECORD_COLLECTIONS_UDF(:cursorVariable, 2)
);
recordVariable := :cursorVariable:RESULT;
IF (ARRAY_SIZE(:recordVariable:column1) = 0) THEN
EXIT;
END IF;
FORALL := ARRAY_SIZE(:recordVariable:column1);
INSERT INTO table2(column1, column2)
(
SELECT
:recordVariable:column1[forIndex],
: recordVariable:column2[forIndex]
FROM
(
SELECT
seq4() AS forIndex
FROM
TABLE(GENERATOR(ROWCOUNT => :FORALL))
)
);
END LOOP;
cursorVariable := (
CALL CLOSE_BULK_CURSOR_UDF(:cursorVariable)
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
Note
This transformation is done only when none of the previously mentioned transformations can be done.
14. Multiple FORALL inside a LOOP clause¶
Note
This pattern applies when there is more than one FORALL in the same procedure and it meets the following structure.
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 20;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
UPDATE table2 SET column1 = '54321' WHERE column2 = collectionVariable(forIndex).column2;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
54321| 2|
54321| 3|
54321| 4|
54321| 5|
54321| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
* FROM
table1
);
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
UPDATE table2
SET column1 = '54321'
FROM
(
SELECT
* FROM
table1) AS collectionVariable
WHERE
column2 = collectionVariable.column2;
END;
$$;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
54321| 2|
54321| 3|
54321| 4|
54321| 5|
54321| 6|
15. Multiple FORALL inside different LOOP clauses¶
Note
This pattern applies when there is more than one FORALL in the same procedure and it meets the following structure.
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
CURSOR cursorVariable2 IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
TYPE collectionTypeDefinition2 IS
TABLE OF table1%ROWTYPE;
collectionVariable2 collectionTypeDefinition2;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
END LOOP;
CLOSE cursorVariable;
OPEN cursorVariable2;
LOOP
FETCH cursorVariable2 BULK COLLECT INTO collectionVariable2 limit 2;
EXIT WHEN collectionVariable2.COUNT = 0;
FORALL forIndex IN collectionVariable2.FIRST..collectionVariable2.LAST
UPDATE table2 SET column1 = '54321' WHERE column2 = collectionVariable2(forIndex).column2;
END LOOP;
CLOSE cursorVariable2;
END;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
54321| 2|
54321| 3|
54321| 4|
54321| 5|
54321| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
* FROM
table1
);
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
UPDATE table2
SET column1 = '54321'
FROM
(
SELECT
* FROM
table1) AS collectionVariable2
WHERE
column2 = collectionVariable2.column2;
END;
$$;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
54321| 2|
54321| 3|
54321| 4|
54321| 5|
54321| 6|
16. FORALL with MERGE INTO with LOG ERRORS¶
Warning
This pattern is not yet implemmented
Oracle
CREATE OR REPLACE PROCEDURE procedure_example (
department_id_in IN source_table.DepartmentID%TYPE)
IS
TYPE employee_ids_t IS TABLE OF source_table%ROWTYPE
INDEX BY PLS_INTEGER;
employee_list employee_ids_t;
BEGIN
SELECT *
BULK COLLECT INTO employee_list
FROM source_table
WHERE DepartmentID = procedure_example.department_id_in;
FORALL indx IN 1 .. employee_list.COUNT
MERGE INTO target_table
USING (SELECT * FROM DUAL) src
ON (id = employee_list(indx).id)
WHEN MATCHED THEN
UPDATE SET
name = employee_list(indx).Name
WHEN NOT MATCHED THEN
INSERT (Id, Name, DepartmentID)
VALUES (employee_list(indx).Id, employee_list(indx).Name, employee_list(indx).DepartmentID)
LOG ERRORS INTO error_table('MERGE INTO ERROR')
REJECT LIMIT UNLIMITED;
END;
CALL procedure_example(10);
select * from target_table;
select * from error_table;
ID| NAME| DEPARTMENTID|
-----+--------+-------------+
101| Anurag| 10|
ORA_ERR_NUMBER$| ORA_ERR_MESG$ | ORA_ERR_ROWID$| ORA_ERR_OPTYP$ | ORA_ERR_TAG$ |
---------------+--------------------------------------------------------------------------------------+-------------------+----------------+--------------------+
12899| ORA-12899: value too large for column "TARGET_TABLE"."NAME" (actual: 15, maximum: 10)| AK6vdpADDAAABI7AAA| U |. MERGE INTO ERROR |
Snowflake¶
--Generated by SnowConvert---------------
CREATE OR REPLACE TRANSIENT TABLE target_staging_table(
Id INT PRIMARY KEY,
Name VARCHAR2(10) NOT NULL,
DepartmentID INT REFERENCES parent_table(Id)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
--Generated by SnowConvert---------------
CREATE OR REPLACE PROCEDURE procedure_example (DEPARTMENT_ID_IN INT /*** MSC-WARNING - MSCEWI3129 - TYPE ATTRIBUTE 'employees.DepartmentID%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CREATE OR REPLACE TEMP TABLE SOURCE_TEMPORAL AS
WITH source_data as (
SELECT *
FROM source_table
WHERE DEPARTMENTID =: DEPARTMENT_ID_IN
)
SELECT source_data.*, parent_table.id as PARENT_KEY
FROM source_data
left join parent_table on source_data.DepartmentID = parent_table.id;
--All records violating foreign key integrity
INSERT INTO error_table (ERROR, COLUMN_NAME, REJECTED_RECORD)
SELECT
'Foreign Key Constraint Violated' ERROR,'KEY_COL' COLUMN_NAME, id
FROM SOURCE_TEMPORAL
WHERE PARENT_KEY IS NULL;
DELETE FROM SOURCE_TEMPORAL
WHERE PARENT_KEY IS NULL;
BEGIN
MERGE INTO target_table
USING SOURCE_TEMPORAL SRC
ON SRC.id = target_table.id
WHEN MATCHED THEN
UPDATE SET
name = SRC.name
WHEN NOT MATCHED THEN
INSERT (Id, Name, DepartmentID)
VALUES (SRC.Id, SRC.Name, SRC.DepartmentID);
EXCEPTION
WHEN OTHER THEN
CREATE OR REPLACE TEMPORARY STAGE my_int_stage
COPY_OPTIONS = (ON_ERROR='continue');
--Create my file and populate with data
COPY INTO @my_int_stage/my_file FROM (
SELECT * exclude(PARENT_KEY) FROM SOURCE_TEMPORAL
) OVERWRITE = TRUE ;
COPY INTO target_staging_table(id, name, DepartmentID)
FROM (
SELECT
-- distinct
t.$1, t.$2, t.$3
FROM @my_int_stage/my_file t
) ON_ERROR = CONTINUE;
INSERT INTO ERROR_TABLE (ERROR, FILE, LINE, CHARACTER, CATEGORY, CODE, SQL_STATE, COLUMN_NAME, ROW_NUMBER, REJECTED_RECORD)
SELECT
ERROR, FILE,LINE, CHARACTER, CATEGORY, CODE, SQL_STATE, COLUMN_NAME, ROW_NUMBER, REJECTED_RECORD
FROM TABLE(VALIDATE(target_staging_table, JOB_ID => '_last')) order by line; --The last charge on the current session
MERGE INTO target_table
USING target_staging_table staging
ON staging.id = target_table.id
WHEN MATCHED THEN
UPDATE SET
name = staging.name
WHEN NOT MATCHED THEN
INSERT (Id, Name, DepartmentID)
VALUES (staging.Id, staging.Name, staging.DepartmentID);
END;
return 'Awesome!';
END;
$$;
CALL procedure_example(10);
SELECT * FROM target_table;
SELECT * FROM error_table;
ERROR| FILE| LINE| CHARACTER| CATEGORY| CODE| SQL_STATE| COLUMN_NAME| ROW_NUMBER| REJECTED_RECORD| CREATE_TS|
---------------------------------------------------------------------+----------------------+-----+----------+------------+---------+----------+---------------------------------------------------+-----------------------+----------------------------+
User character length limit (10) exceeded by string 'Anurag111111111'| my_file_0_0_0.csv.gz| 1| 5| conversion| 100074| 54000| """TARGET_STAGING_TABLE""[""NAME"":2]"| 1| 101,Anurag111111111,10| 2023-08-03T14:33:40.978Z|
17. FORALL with INSERT with LOG ERRORS¶
Warning
This pattern is not yet implemmented
Oracle
CREATE OR REPLACE PROCEDURE procedure_example (
department_id_in IN source_table.DepartmentID%TYPE)
IS
TYPE employee_ids_t IS TABLE OF source_table%ROWTYPE
INDEX BY PLS_INTEGER;
employee_list employee_ids_t;
BEGIN
SELECT *
BULK COLLECT INTO employee_list
FROM source_table
WHERE DepartmentID = procedure_example.department_id_in;
FORALL indx IN 1 .. employee_list.COUNT
INSERT INTO target_table(Id, Name, DepartmentID)
VALUES (employee_list(indx).Id, employee_list(indx).Name, employee_list(indx).DepartmentID)
LOG ERRORS INTO error_table('MERGE INTO ERROR')
REJECT LIMIT UNLIMITED;
END;
ID| NAME| DEPARTMENTID|
-----+--------+-------------+
101| Anurag| 10|
ORA_ERR_NUMBER$| ORA_ERR_MESG$ | ORA_ERR_ROWID$| ORA_ERR_OPTYP$ | ORA_ERR_TAG$ |
---------------+--------------------------------------------------------------------------------------+-------------------+----------------+--------------------+
12899| ORA-12899: value too large for column "TARGET_TABLE"."NAME" (actual: 15, maximum: 10)| AK6vdpADDAAABI7AAA| U |. MERGE INTO ERROR |
Snowflake¶
--Generated by SnowConvert---------------
CREATE OR REPLACE TRANSIENT TABLE target_staging_table(
Id INT PRIMARY KEY,
Name VARCHAR2(10) NOT NULL,
DepartmentID INT REFERENCES parent_table(Id)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
--Generated by SnowConvert---------------
CREATE OR REPLACE PROCEDURE procedure_example (DEPARTMENT_ID_IN INT /*** MSC-WARNING - MSCEWI3129 - TYPE ATTRIBUTE 'employees.DepartmentID%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CREATE OR REPLACE TEMP TABLE SOURCE_TEMPORAL AS
WITH source_data as (
SELECT *
FROM source_table
WHERE DEPARTMENTID =: DEPARTMENT_ID_IN
)
SELECT source_data.*, parent_table.id as PARENT_KEY
FROM source_data
left join parent_table on source_data.DepartmentID = parent_table.id;
--All records violating foreign key integrity
INSERT INTO error_table (ERROR, COLUMN_NAME, REJECTED_RECORD)
SELECT
'Foreign Key Constraint Violated' ERROR,'KEY_COL' COLUMN_NAME, id
FROM SOURCE_TEMPORAL
WHERE PARENT_KEY IS NULL;
DELETE FROM SOURCE_TEMPORAL
WHERE PARENT_KEY IS NULL;
BEGIN
INSERT INTO target_table (Id, Name, DepartmentID)
SELECT SRC.Id, SRC.Name, SRC.DepartmentID FROM SOURCE_TEMPORAL SRC;
EXCEPTION
WHEN OTHER THEN
CREATE OR REPLACE TEMPORARY STAGE my_int_stage
COPY_OPTIONS = (ON_ERROR='continue');
--Create my file and populate with data
COPY INTO @my_int_stage/my_file FROM (
SELECT * exclude(PARENT_KEY) FROM SOURCE_TEMPORAL
) OVERWRITE = TRUE ;
COPY INTO target_staging_table(id, name, DepartmentID)
FROM (
SELECT
-- distinct
t.$1, t.$2, t.$3
FROM @my_int_stage/my_file t
) ON_ERROR = CONTINUE;
INSERT INTO ERROR_TABLE (ERROR, FILE, LINE, CHARACTER, CATEGORY, CODE, SQL_STATE, COLUMN_NAME, ROW_NUMBER, REJECTED_RECORD)
SELECT
ERROR, FILE,LINE, CHARACTER, CATEGORY, CODE, SQL_STATE, COLUMN_NAME, ROW_NUMBER, REJECTED_RECORD
FROM TABLE(VALIDATE(target_staging_table, JOB_ID => '_last')) order by line; --The last charge on the current session
INSERT INTO target_table (Id, Name, DepartmentID)
SELECT staging.Id, staging.Name, staging.DepartmentID FROM target_staging_table staging;
END;
END;
$$;
CALL procedure_example(10);
SELECT * FROM target_table;
SELECT * FROM error_table;
ERROR| FILE| LINE| CHARACTER| CATEGORY| CODE| SQL_STATE| COLUMN_NAME| ROW_NUMBER| REJECTED_RECORD| CREATE_TS|
---------------------------------------------------------------------+----------------------+-----+----------+------------+---------+----------+---------------------------------------------------+-----------------------+----------------------------+
User character length limit (10) exceeded by string 'Anurag111111111'| my_file_0_0_0.csv.gz| 1| 5| conversion| 100074| 54000| """TARGET_STAGING_TABLE""[""NAME"":2]"| 1| 101,Anurag111111111,10| 2023-08-03T14:33:40.978Z|
Known Issues¶
No issues were found.
Related EWIs¶
SSC-EWI-0030: The statement below has usages of dynamic SQL.
SSC-EWI-0036: Data type converted to another data type.
SSC-EWI-0056: Create Type Not Supported.
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-OR0049: Package constants in stateful package are not supported yet.
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-0015: Referenced custom type in query not found.
SSC-PRF-0001: This statement has usages of cursor fetch bulk operations.
SSC-PRF-0003: Fetch inside a loop is considered a complex pattern, this could degrade Snowflake performance.
IF¶
Description¶
The IF
statement either runs or skips a sequence of one or more statements, depending on the value of a BOOLEAN
expression. For more information regarding Oracle IF, check here.
IF boolean_expression THEN
statement
[ statement ]...
[
ELSIF boolean_expression THEN
statement
[ statement ]... ]...
[
ELSE
statement [ statement ]... ] END IF ;
IF ( <condition> ) THEN
<statement>;
[ <statement>; ... ]
[
ELSEIF ( <condition> ) THEN
<statement>;
[ <statement>; ... ]
]
[
ELSE
<statement>;
[ <statement>; ... ]
]
END IF;
Sample Source Patterns¶
Sample auxiliar table¶
CREATE TABLE if_table(col1 varchar(30));
CREATE OR REPLACE TABLE PUBLIC.if_table (col1 varchar(30));
Possible IF variations¶
Oracle¶
CREATE OR REPLACE PROCEDURE ifExample1 ( flag NUMBER )
IS
BEGIN
IF flag = 1 THEN
INSERT INTO if_table(col1) VALUES ('one');
END IF;
END;
CALL ifExample1(1);
SELECT * FROM if_table;
CREATE OR REPLACE PROCEDURE ifExample2 ( flag NUMBER )
IS
BEGIN
IF flag = 1 THEN
INSERT INTO if_table(col1) VALUES ('one');
ELSE
INSERT INTO if_table(col1) VALUES ('Unexpected input.');
END IF;
END;
CALL ifExample2(2);
SELECT * FROM if_table;
CREATE OR REPLACE PROCEDURE ifExample3 ( flag NUMBER )
IS
BEGIN
IF flag = 1 THEN
INSERT INTO if_table(col1) VALUES ('one');
ELSIF flag = 2 THEN
INSERT INTO if_table(col1) VALUES ('two');
ELSIF flag = 3 THEN
INSERT INTO if_table(col1) VALUES ('three');
END IF;
END;
CALL ifExample3(3);
SELECT * FROM if_table;
CREATE OR REPLACE PROCEDURE ifExample4 ( flag NUMBER )
IS
BEGIN
IF flag = 1 THEN
INSERT INTO if_table(col1) VALUES ('one');
ELSIF flag = 2 THEN
INSERT INTO if_table(col1) VALUES ('two');
ELSIF flag = 3 THEN
INSERT INTO if_table(col1) VALUES ('three');
ELSE
INSERT INTO if_table(col1) VALUES ('Unexpected input.');
END IF;
END;
CALL ifExample4(4);
SELECT * FROM if_table;
|COL1|
|----|
|one |
|COL1 |
|-----------------|
|Unexpected input.|
|COL1 |
|-----|
|three|
|COL1 |
|-----------------|
|Unexpected input.|
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE ifExample1 (flag NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
IF (:flag = 1) THEN
INSERT INTO if_table(col1) VALUES ('one');
END IF;
END;
$$;
CALL ifExample1(1);
SELECT * FROM
if_table;
CREATE OR REPLACE PROCEDURE ifExample2 (flag NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
IF (:flag = 1) THEN
INSERT INTO if_table(col1) VALUES ('one');
ELSE
INSERT INTO if_table(col1) VALUES ('Unexpected input.');
END IF;
END;
$$;
CALL ifExample2(2);
SELECT * FROM
if_table;
CREATE OR REPLACE PROCEDURE ifExample3 (flag NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
IF (:flag = 1) THEN
INSERT INTO if_table(col1) VALUES ('one');
ELSEIF (:flag = 2) THEN
INSERT INTO if_table(col1) VALUES ('two');
ELSEIF (:flag = 3) THEN
INSERT INTO if_table(col1) VALUES ('three');
END IF;
END;
$$;
CALL ifExample3(3);
SELECT * FROM
if_table;
CREATE OR REPLACE PROCEDURE ifExample4 (flag NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
IF (:flag = 1) THEN
INSERT INTO if_table(col1) VALUES ('one');
ELSEIF (:flag = 2) THEN
INSERT INTO if_table(col1) VALUES ('two');
ELSEIF (:flag = 3) THEN
INSERT INTO if_table(col1) VALUES ('three');
ELSE
INSERT INTO if_table(col1) VALUES ('Unexpected input.');
END IF;
END;
$$;
CALL ifExample4(4);
SELECT * FROM if_table;
|COL1|
|----|
|one |
|COL1 |
|-----------------|
|Unexpected input.|
|COL1 |
|-----|
|three|
|COL1 |
|-----------------|
|Unexpected input.|
Known issues¶
No issues were found.
Related EWIS¶
No related EWIs.
IS EMPTY¶
Warning
This section is a work in progress; information may change in the future.
Description¶
Use the IS [NOT] EMPTY conditions to test whether a specified nested table is empty, regardless whether any elements of the collection are NULL. (Documentation).
Oracle syntax¶
nested_table IS [ NOT ] EMPTY
Sample Source Patterns¶
Oracle¶
The following example shows the usage of the IS EMPTY statement. The statement is applied over a nested table which uses a UDT as the definition type. The output shows the name of the employees who do not have a phone number.
CREATE TYPE phone_number_type AS OBJECT (phone_number VARCHAR2(30));
/
CREATE TYPE phone_number_list AS TABLE OF phone_number_type;
CREATE TABLE employee (
emp_id NUMBER,
emp_name VARCHAR2(50),
phone_numbers_col phone_number_list
) NESTED TABLE phone_numbers_col STORE AS nested_tab return as value;
INSERT INTO employee VALUES (
1,
'John Doe',
phone_number_list(phone_number_type('1234567890'))
);
/
INSERT INTO employee VALUES (
2,
'Jane Smith',
phone_number_list()
);
SELECT emp_name
FROM employee
WHERE phone_numbers_col IS EMPTY;
EMP_NAME |
---|
Jane Smith |
Snowflake¶
The Snowflake query shown below is the equivalence of the functionality of the IS EMPTY statement. Particularly, the IS EMPTY statement has a difference between a NULL and an EMPTY object.
Notice that the User-Defined Types are transformed to a VARIANT. The VARIANT type in Snowflake is able to store objects and arrays. Since a nested table is a sequence of information, the ARRAY type is the most suitable type to redefine them and verify is the object ARRAY is empty.
The ARRAY_SIZE equivalent solution also allows to ask for nullability of the nested table (transformed to VARIANT). In other words, the VARIANT type can also store NULLs and empty ARRAYs.
!!!RESOLVE EWI!!! /*** SSC-EWI-0056 - CUSTOM TYPES ARE NOT SUPPORTED IN SNOWFLAKE BUT REFERENCES TO THIS CUSTOM TYPE WERE CHANGED TO VARIANT ***/!!!
CREATE TYPE phone_number_type AS OBJECT (phone_number VARCHAR2(30))
;
!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'NESTED TABLE' NODE ***/!!!
CREATE TYPE phone_number_list AS TABLE OF phone_number_type;
CREATE OR REPLACE TABLE employee (
emp_id NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
emp_name VARCHAR(50),
phone_numbers_col VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'phone_number_list' USAGE CHANGED TO VARIANT ***/!!!
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE VIEW PUBLIC.employee_view
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "" }}'
AS
SELECT
emp_id,
emp_name,
phone_numbers_col
FROM
employee;
INSERT INTO employee
VALUES (
1,
'John Doe',
phone_number_list(phone_number_type('1234567890') !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'phone_number_type' NODE ***/!!!) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'phone_number_list' NODE ***/!!!
);
INSERT INTO employee
VALUES (
2,
'Jane Smith',
phone_number_list() !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'phone_number_list' NODE ***/!!!
);
SELECT emp_name
FROM
employee
WHERE
ARRAY_SIZE( phone_numbers_col) = 0;
EMP_NAME |
---|
Jane Smith |
Other possible combinations¶
Description | Oracle | Snowflake |
---|---|---|
Ask for a IS NOT EMPTY |
|
|
Ask for NULL instead of EMPTY |
|
|
Known Issues¶
1. User-defined types are being transformed into Variant.¶
User-defined types are not supported thus they are transformed into Variant types which could need manual effort to ensure some functionalities.
Review the following page for more information:
2. Nested tables are not supported.¶
Nested tables are not currently supported. The best approach based on this equivalence is to handle nested tables as Variant but declare Arrays with JSON data inside and execute the PARSE_JSON Snowflake function to populate the nested information.
Review the following pages for more information:
3. Insert statements are not supported for User-defined types.¶
Since User-defined types are not supported in consequence the Insert statements to these types are not supported. Specifically in nested tables, the INSERT INTO ... VALUES
statement has to be changed to a INSERT INTO ...SELECT
because the ARRAY_CONSTRUCT function is expected to be used in that pattern.
Review the following page for more information:
4. Logic should be adapted to ARRAY
types.¶
Since the nested tables should be equivalently transformed to VARIANT
and behave as ARRAYs,
the functionality and logic of implementing procedures and interaction with the data should be adapted.
Review the following examples:
4.1 Procedures equivalence¶
create or replace procedure proc1
as
col1 phone_number_list:= phone_number_list();
begin
IF col1 IS EMPTY
THEN
dbms_output.put_line('IS EMPTY');
END IF;
end;
CREATE OR REPLACE PROCEDURE proc1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
col1 VARIANT /*** SSC-FDM-0015 - REFERENCED CUSTOM TYPE 'phone_number_list' IN QUERY NOT FOUND, USAGES MAY BE AFFECTED ***/ := phone_number_list() !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'phone_number_list' NODE ***/!!!;
BEGIN
IF (ARRAY_SIZE(:col1) = 0) THEN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF('IS EMPTY');
END IF;
END;
$$;
PROC1 |
---|
IS EMPTY |
4.2 Select statements¶
Outputs may differ from tables to ARRAYs
.
Oracle¶
SELECT
t.*
FROM
employee e,
table(e.phone_numbers_col) t
WHERE
emp_id = 1;
PHONE_NUMBER |
---|
1234567890 |
Snowflake¶
SELECT
t.*
FROM
employee e,
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0035 - TABLE FUNCTION IS NOT SUPPORTED WHEN IT IS USED AS A COLLECTION OF EXPRESSIONS ***/!!!
table(e.phone_numbers_col) t
WHERE
emp_id = 1;
PHONE_NUMBERS_COL |
---|
[ 1234567890 ] |
Related EWIs¶
SSC-EWI-0056: Create Type Not Supported.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-0073: Pending Functional Equivalence Review.
SSC-EWI-OR0035: The table function is not supported when it is used as a collection of expressions.
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-0015: Referenced custom type in query not found.
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
LOCK TABLE¶
Note
Non-relevant statement.
Warning
Notice that this statement isremoved from the migrationbecause it is a non-relevant syntax. It means that it is not required in Snowflake.
Description¶
In Oracle, the LOCK TABLE
statement allows to explicitly acquire a shared or exclusive table lock on the specified table. The table lock lasts until the end of the current transaction. Review more information here.
Syntax
LOCK TABLE tableName IN { SHARE | EXCLUSIVE } MODE
Sample Source Patterns¶
Locking table¶
Notice that in this example the LOCK TABLE
statement has been deleted. This is because Snowflake handles locking in a different method through transactions.
LOCK TABLE table1 IN EXCLUSIVE MODE;
[Empty output]
LOG ERROR¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The FORALL
statement runs one DML statement multiple times, with different values in the VALUES
and WHERE
clauses. (Oracle PL/SQL Language Reference FORALL Statement).
FORALL index IN bounds_clause [ SAVE ] [ EXCEPTIONS ] dml_statement ;
Warning
Snowflake Scripting has no direct equivalence with the FORALL
statement, however can be emulated with different workarounds to get functional equivalence.
Sample Source Patterns¶
Setup Data¶
Oracle¶
CREATE TABLE error_table (
ORA_ERR_NUMBER$ NUMBER,
ORA_ERR_MESG$ VARCHAR2(2000),
ORA_ERR_ROWID$ ROWID,
ORA_ERR_OPTYP$ VARCHAR2(2),
ORA_ERR_TAG$ VARCHAR2(2000)
);
--departments
CREATE TABLE parent_table(
Id INT PRIMARY KEY,
Name VARCHAR2(10)
);
INSERT INTO parent_table VALUES (10, 'IT');
INSERT INTO parent_table VALUES (20, 'HR');
INSERT INTO parent_table VALUES (30, 'INFRA');
--employees
CREATE TABLE source_table(
Id INT PRIMARY KEY,
Name VARCHAR2(20) NOT NULL,
DepartmentID INT REFERENCES parent_table(Id)
);
INSERT INTO source_table VALUES (101, 'Anurag111111111', 10);
INSERT INTO source_table VALUES (102, 'Pranaya11111111', 20);
INSERT INTO source_table VALUES (103, 'Hina11111111111', 30);
--a copy of source
CREATE TABLE target_table(
Id INT PRIMARY KEY,
Name VARCHAR2(10) NOT NULL,
DepartmentID INT REFERENCES parent_table(Id)
);
INSERT INTO target_table VALUES (101, 'Anurag', 10);
Snowflake¶
CREATE OR REPLACE TABLE error_table (
"ORA_ERR_NUMBER$" NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
"ORA_ERR_MESG$" VARCHAR(2000),
"ORA_ERR_ROWID$" VARCHAR(18) !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWID DATA TYPE CONVERTED TO VARCHAR ***/!!!,
"ORA_ERR_OPTYP$" VARCHAR(2),
"ORA_ERR_TAG$" VARCHAR(2000)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
--departments
CREATE OR REPLACE TABLE parent_table (
Id INT PRIMARY KEY,
Name VARCHAR(10)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO parent_table
VALUES (10, 'IT');
INSERT INTO parent_table
VALUES (20, 'HR');
INSERT INTO parent_table
VALUES (30, 'INFRA');
--employees
CREATE OR REPLACE TABLE source_table (
Id INT PRIMARY KEY,
Name VARCHAR(20) NOT NULL,
DepartmentID INT REFERENCES parent_table (Id)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO source_table
VALUES (101, 'Anurag111111111', 10);
INSERT INTO source_table
VALUES (102, 'Pranaya11111111', 20);
INSERT INTO source_table
VALUES (103, 'Hina11111111111', 30);
--a copy of source
CREATE OR REPLACE TABLE target_table (
Id INT PRIMARY KEY,
Name VARCHAR(10) NOT NULL,
DepartmentID INT REFERENCES parent_table (Id)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO target_table
VALUES (101, 'Anurag', 10);
1. MERGE INTO Inside a FORALL¶
Oracle
The three cases below have the same transformation to Snowflake Scripting and are functionally equivalent.
CREATE OR REPLACE PROCEDURE procedure_example (
department_id_in IN source_table.DepartmentID%TYPE)
IS
TYPE employee_ids_t IS TABLE OF source_table%ROWTYPE
INDEX BY PLS_INTEGER;
employee_list employee_ids_t;
BEGIN
SELECT *
BULK COLLECT INTO employee_list
FROM source_table
WHERE DepartmentID = procedure_example.department_id_in;
FORALL indx IN 1 .. employee_list.COUNT
MERGE INTO target_table
USING (SELECT * FROM DUAL) src
ON (id = employee_list(indx).id)
WHEN MATCHED THEN
UPDATE SET
name = employee_list(indx).Name
WHEN NOT MATCHED THEN
INSERT (Id, Name, DepartmentID)
VALUES (employee_list(indx).Id, employee_list(indx).Name, employee_list(indx).DepartmentID)
LOG ERRORS INTO error_table('MERGE INTO ERROR')
REJECT LIMIT UNLIMITED;
END;
CALL procedure_example(10);
select * from target_table;
select * from error_table;
ID| NAME| DEPARTMENTID|
-----+--------+-------------+
101| Anurag| 10|
ORA_ERR_NUMBER$| ORA_ERR_MESG$ | ORA_ERR_ROWID$| ORA_ERR_OPTYP$ | ORA_ERR_TAG$ |
---------------+--------------------------------------------------------------------------------------+-------------------+----------------+--------------------+
12899| ORA-12899: value too large for column "TARGET_TABLE"."NAME" (actual: 15, maximum: 10)| AK6vdpADDAAABI7AAA| U |. MERGE INTO ERROR |
Snowflake
CREATE OR REPLACE PROCEDURE procedure_example (department_id_in VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-OR0129 - TYPE ATTRIBUTE 'source_table.DepartmentID%TYPE' COULD NOT BE RESOLVED, SO IT WAS TRANSFORMED TO VARIANT ***/!!!)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE employee_ids_t IS TABLE OF source_table%ROWTYPE
-- INDEX BY PLS_INTEGER;
employee_list VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'employee_ids_t' USAGE CHANGED TO VARIANT ***/!!!;
FORALL INTEGER;
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'RECORDS AND COLLECTIONS' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
SELECT *
BULK COLLECT INTO employee_list
FROM source_table
WHERE DepartmentID = procedure_example.department_id_in;
FORALL := ARRAY_SIZE(:employee_list);
MERGE INTO target_table
USING (SELECT * FROM
(
SELECT
seq4() AS indx
FROM
TABLE(GENERATOR(ROWCOUNT => :FORALL))
)) src
ON (id = : employee_list[indx]:id)
WHEN MATCHED THEN
UPDATE SET
name = : employee_list[indx]:Name
WHEN NOT MATCHED THEN
INSERT (Id, Name, DepartmentID)
VALUES (:employee_list[indx]:Id, : employee_list[indx]:Name, : employee_list[indx]:DepartmentID)
-- --** SSC-FDM-OR0031 - THE ERROR LOGGING CLAUSE IN DML STATEMENTS IS NOT SUPPORTED BY SNOWFLAKE **
-- LOG ERRORS INTO error_table('MERGE INTO ERROR')
-- REJECT LIMIT UNLIMITED
;
END;
$$;
CALL procedure_example(10);
select * from
target_table;
select * from
error_table;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
Note
The EWIs MSCCP0005 and SSC-PRF-0003 are added in every FETCH BULK COLLECT occurrence into FORALL statement.
2. FORALL With INSERT INTO¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
* FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
3. FORALL With Multiple Fetched Collections¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
column1Collection dbms_sql.NUMBER_table;
column2Collection dbms_sql.NUMBER_table;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO column1Collection, column2Collection limit 20;
EXIT WHEN column1Collection.COUNT = 0;
FORALL forIndex IN 1..column1Collection.COUNT
INSERT INTO table2 VALUES (
column1Collection(forIndex),
column2Collection(forIndex)
);
END LOOP;
CLOSE cursorVariable;
END;
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
column1Collection dbms_sql.NUMBER_table;
column2Collection dbms_sql.NUMBER_table;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO column1Collection, column2Collection limit 2;
EXIT WHEN column1Collection.COUNT = 0;
FORALL forIndex IN 1..column1Collection.COUNT
UPDATE table2 SET column2 = column2Collection(forIndex)
WHERE column1 = column1Collection(forIndex);
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
1| 2|
COLUMN1| COLUMN2|
--------+--------+
1| 2|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
$1,
$2
FROM
table1
);
END;
$$;
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
UPDATE table2
SET column2 = column1Collection.$2
FROM
(
SELECT
* FROM
table1) AS column1Collection
WHERE
column1 = column1Collection.$1;
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
4. FORALL With Record of Collections¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE recordType IS RECORD(
column1Collection dbms_sql.NUMBER_table,
column2Collection dbms_sql.NUMBER_table
);
columnRecord recordType;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO columnRecord.column1Collection, columnRecord.column2Collection limit 20;
FORALL forIndex IN 1..columnRecord.column1Collection.COUNT
INSERT INTO table2 VALUES (
columnRecord.column1Collection(forIndex),
columnRecord.column2Collection(forIndex)
);
EXIT WHEN cursorVariable%NOTFOUND;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
$1,
$2
FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
5. FORALL With Dynamic SQL¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
cursorVariable SYS_REFCURSOR;
TYPE collectionTypeDefinition IS
TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
query VARCHAR(200) := 'SELECT * FROM table1';
BEGIN
OPEN cursorVariable FOR query;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
INSERT INTO table2 VALUES collectionVariable(forIndex);
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
query VARCHAR(200) := 'SELECT * FROM
table1';
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE 'CREATE OR REPLACE TEMPORARY TABLE query AS ' || :query;
INSERT INTO table2
(
SELECT
*
FROM
query
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000
6. FORALL Without LOOPS¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
SELECT * BULK COLLECT INTO collectionVariable FROM table1;
FORALL forIndex IN 1..collectionVariable.COUNT
INSERT INTO table2 VALUES (
collectionVariable (forIndex).column1,
collectionVariable (forIndex).column2
);
collectionVariable.DELETE;
END;
COLUMN1| COLUMN2|
--------+--------+
1| 2|
1| 2|
2| 3|
3| 4|
4| 5|
5| 6|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
INSERT INTO table2
(
SELECT
column1,
column2
FROM
table1
);
END;
$$;
COLUMN1| COLUMN2|
--------------------+-----------------------+
1.000000000000000000| 2.000000000000000000|
1.000000000000000000| 2.000000000000000000|
2.000000000000000000| 3.000000000000000000|
3.000000000000000000| 4.000000000000000000|
4.000000000000000000| 5.000000000000000000|
5.000000000000000000| 6.000000000000000000|
7. FORALL With UPDATE Statements¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
UPDATE table2 SET column1 = '54321' WHERE column2 = collectionVariable(forIndex).column2;
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
COLUMN1| COLUMN2|
--------+--------+
54321| 2|
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
UPDATE table2
SET column1 = '54321'
FROM
(
SELECT
* FROM
table1) AS collectionVariable
WHERE
column2 = collectionVariable.column2;
END;
$$;
ambiguous column name 'COLUMN2'
8. FORALL With DELETE Statements¶
Oracle¶
CREATE OR REPLACE PROCEDURE myProcedure IS
CURSOR cursorVariable IS
SELECT * FROM table1;
TYPE collectionTypeDefinition IS TABLE OF table1%ROWTYPE;
collectionVariable collectionTypeDefinition;
BEGIN
OPEN cursorVariable;
LOOP
FETCH cursorVariable BULK COLLECT INTO collectionVariable limit 2;
EXIT WHEN collectionVariable.COUNT = 0;
FORALL forIndex IN collectionVariable.FIRST..collectionVariable.LAST
DELETE FROM table2 WHERE column2 = collectionVariable(forIndex).column2;
collectionVariable.DELETE;
END LOOP;
CLOSE cursorVariable;
END;
no data found
Snowflake¶
CREATE OR REPLACE PROCEDURE myProcedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
DELETE FROM
table2
USING (
SELECT
* FROM
table1) collectionVariable
WHERE
table2.column2 = collectionVariable.column2;
END;
$$;
Query produced no results
Known Issues¶
No issues were found.
Related EWIs¶
SSC-EWI-0030: The statement below has usages of dynamic SQL.
SSC-EWI-0036: Data type converted to another data type.
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-OR0129: TYPE attribute could not be resolved.
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-OR0031: The error logging clause in DML statements is not supported by Snowflake.
SSC-PRF-0001: This statement has usages of cursor fetch bulk operations.
SSC-PRF-0003: Fetch inside a loop is considered a complex pattern, this could degrade Snowflake performance.
LOOP¶
Description¶
With each iteration of the basic LOOP
statement, its statements run and control returns to the top of the loop. The LOOP
statement ends when a statement inside the loop transfers control outside the loop or raises an exception.
(Oracle PL/SQL Language Reference BASIC LOOP Statement)
LOOP statement... END LOOP [ label ] ;
LOOP
<statement>;
[ <statement>; ... ]
END LOOP [ <label> ] ;
Oracle BASIC LOOP
behavior can also be modified by using the statements:
Sample Source Patterns¶
Loop simple case¶
This case is functionally equivalent.
Oracle
CREATE TABLE loop_testing_table
(
iterator VARCHAR2(5)
);
CREATE OR REPLACE PROCEDURE loop_procedure
IS
I NUMBER := 1;
J NUMBER := 10;
BEGIN
LOOP
EXIT WHEN I = J;
INSERT INTO loop_testing_table VALUES(TO_CHAR(I));
I := I+1;
END LOOP;
END;
CALL loop_procedure();
SELECT * FROM loop_testing_table;
ITERATOR|
--------+
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
9 |
Snowflake Scripting
CREATE OR REPLACE TABLE loop_testing_table
(
iterator VARCHAR(5)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE loop_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 1;
J NUMBER(38, 18) := 10;
BEGIN
LOOP
IF (:I = :J) THEN
EXIT;
END IF;
INSERT INTO loop_testing_table
VALUES(TO_CHAR(:I));
I := :I +1;
END LOOP;
END;
$$;
CALL loop_procedure();
SELECT * FROM
loop_testing_table;
ITERATOR|
--------+
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
9 |
Known Issues
No issues were found.
Related EWIs
No related EWIs.
OUTPUT PARAMETERS
Description
An output parameter is a parameter whose value is passed out of the stored procedure/function module, back to the calling PL/SQL block. Since the output parameters are not supported by Snowflake Scripting, a solution has been implemented in order to emulate their functionality.
Sample Source Patterns
Sample auxiliary table
CREATE TABLE table01 (col1 NUMBER, col2 NUMBER);
CREATE OR REPLACE TABLE table01 (col1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
col2 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
In the declaration, the OUT
or IN OUT
keywords are removed. The assignment is being emitted the same as the input but to emulate the functionality of the output parameter some statements are being added.
When a procedure with output parameters is being called into another one, some statements are added in order to get and assign the value(s) to the respective argument(s).
Single out parameter
Oracle
-- Procedure with output parameter declaration
CREATE OR REPLACE PROCEDURE proc_with_single_output_parameters(
param1 OUT NUMBER
)
IS
BEGIN
param1 := 123;
END;
-- Procedure with output parameter being called
CREATE OR REPLACE PROCEDURE proc_calling_proc_with_single_output_parameters
IS
var1 NUMBER;
BEGIN
proc_with_single_output_parameters(var1);
INSERT INTO TABLE01 VALUES(var1, -1);
END;
Snowflake Scripting
-- Procedure with output parameter declaration
CREATE OR REPLACE PROCEDURE proc_with_single_output_parameters (param1 NUMBER(38, 18)
)
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
param1 := 123;
RETURN param1;
END;
$$;
-- Procedure with output parameter being called
CREATE OR REPLACE PROCEDURE proc_calling_proc_with_single_output_parameters ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
var1 NUMBER(38, 18);
call_results VARIANT;
BEGIN
call_results := (
CALL
proc_with_single_output_parameters(:var1)
);
var1 := :call_results;
INSERT INTO TABLE01
VALUES(:var1, -1);
END;
$$;
Multiple out parameter
Oracle
-- Procedure with output parameters declaration
CREATE OR REPLACE PROCEDURE proc_with_multiple_output_parameters(
param1 OUT NUMBER,
param2 IN OUT NUMBER
)
IS
BEGIN
param1 := 123;
param2 := 456;
END;
-- Procedure with output parameters being called
CREATE OR REPLACE PROCEDURE proc_calling_proc_with_multiple_output_parameters
IS
var1 NUMBER;
var2 NUMBER;
BEGIN
proc_with_multiple_output_parameters(var1, var2);
INSERT INTO TABLE01 VALUES(var1, var2);
END;
Snowflake Scripting
-- Procedure with output parameters declaration
CREATE OR REPLACE PROCEDURE proc_with_multiple_output_parameters (param1 NUMBER(38, 18), param2 NUMBER(38, 18)
)
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
param1 := 123;
param2 := 456;
RETURN OBJECT_CONSTRUCT('param1', :param1, 'param2', :param2);
END;
$$;
-- Procedure with output parameters being called
--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "TABLE01" **
CREATE OR REPLACE PROCEDURE proc_calling_proc_with_multiple_output_parameters ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
var1 NUMBER(38, 18);
var2 NUMBER(38, 18);
call_results VARIANT;
BEGIN
call_results := (
CALL
proc_with_multiple_output_parameters(:var1, :var2)
);
var1 := :call_results:param1;
var2 := :call_results:param2;
INSERT INTO TABLE01
VALUES(:var1, :var2);
END;
$$;
In order to check that the functionality is being emulated correctly the following query is going to execute the procedure and a SELECT
from the table mentioned before.
Oracle
CALL proc_with_single_output_parameters();
CALL proc_with_multiple_output_parameters();
SELECT * FROM table01;
COL1|COL2
----+----
123 |-1
123 |456
Snowflake Scripting
CALL proc_with_single_output_parameters();
CALL proc_with_multiple_output_parameters();
SELECT * FROM table01;
COL1 | COL2
-----------------------+-----------------------
123.000000000000000000 | -1
123.000000000000000000 | 456.000000000000000000
Customer data type OUT parameters
when the output parameter is a customer type, the process is similar to a regular data type.
Oracle
CREATE OR REPLACE PROCEDURE procedure_udtype_out_params (
p_employee_id NUMBER,
p_address OUT address_type
)
AS
BEGIN
-- Retrieve the employee's address based on the employee ID.
SELECT home_address INTO p_address
FROM employees
WHERE employee_id = p_employee_id;
END;
Snowflake Scripting
CREATE OR REPLACE PROCEDURE procedure_udtype_out_params (p_employee_id NUMBER(38, 18), p_address VARIANT /*** SSC-FDM-0015 - REFERENCED CUSTOM TYPE 'address_type' IN QUERY NOT FOUND, USAGES MAY BE AFFECTED ***/
)
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
-- Retrieve the employee's address based on the employee ID.
SELECT home_address INTO
:p_address
FROM
employees
WHERE employee_id = :p_employee_id;
RETURN p_address;
END;
$$;
Known Issues
1. Procedures with output parameters inside packages may not work correctly
Currently, there is an issue collecting the semantic information of procedures that reside inside packages, which is why the transformation for output parameters may work partially or not work at all. There is already a work in progress to resolve this issue.
2. Some data types may not work properly
As seen in the transformation, when retrieving the value from the called procedures, an implicit cast is performed from VARIANT to the type specified by the variable. Since there are a lot of possible data types, some casts may fail or contain different data.
Related EWIs
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-0007: Element with missing dependencies.
SSC-FDM-0015: Data Type Not Recognized.
PROCEDURE CALL
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
This section describes the syntax for subprogram invocations within PL blocks, such as procedures or anonymous blocks.
For more information on this subject, please refer to Oracle’s Subprogram documentation: (Oracle PL/SQL Language Reference Subprogram Invocation Statement)
Procedure calls can be migrated to Snowflake as long as there are no optional parameters and their order matches the formal parameters. Please note that Procedure invocations get migrated to a Call statement.
<subprogram invocation> := subprogram_name [ ( [ parameter [, parameter]... ] ) ]
<parameter> := {
<actual parameter>
| <formal parameter name> => <actual parameter>
}
Snowflake Scripting has support for this statement, albeit with some functional differences.
<subprogram invocation> := CALL subprogram_name [ ( [ parameter [, parameter]... ] ) ]
<parameter> := {
<actual parameter>
| <formal parameter name> => <actual parameter>
}
Sample Source Patterns¶
Note
Consider the next table and procedure for the examples below.
CREATE TABLE procedure_call_test_table(
col1 INTEGER
);
-- Simple Called procedure
CREATE OR REPLACE PROCEDURE called_procedure (param1 INTEGER)
AS
BEGIN
INSERT INTO procedure_call_test_table VALUES (param1);
END;
CREATE OR REPLACE TABLE procedure_call_test_table (
col1 INTEGER
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
-- Simple Called procedure
CREATE OR REPLACE PROCEDURE called_procedure (param1 INTEGER)
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 procedure_call_test_table
VALUES (:param1);
END;
$$;
Simple call¶
Oracle¶
CREATE OR REPLACE PROCEDURE simple_calling_procedure
AS
BEGIN
called_procedure(1);
END;
CALL simple_calling_procedure();
SELECT * FROM procedure_call_test_table;
COL1|
----+
1|
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE simple_calling_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CALL
called_procedure(1);
END;
$$;
CALL simple_calling_procedure();
--** SSC-FDM-0007 - MISSING DEPENDENT OBJECT "procedure_call_test_table" **
SELECT * FROM
procedure_call_test_table;
COL1|
----+
1|
Calling a procedure with an optional parameter¶
Warning
This sample contains manual intervention for some functional differences and is used to explain them. For more information on these differences, please check the Known Issues section below.
Oracle¶
-- Procedure with optional parameters
CREATE OR REPLACE PROCEDURE proc_optional_parameters (param1 INTEGER, param2 INTEGER := 8, param3 INTEGER)
AS
BEGIN
INSERT INTO procedure_call_test_table VALUES (param1);
INSERT INTO procedure_call_test_table VALUES (param2);
INSERT INTO procedure_call_test_table VALUES (param3);
END;
CREATE OR REPLACE PROCEDURE calling_procedure
AS
BEGIN
-- positional convention
proc_optional_parameters(1, 2, 3);
-- named convention
proc_optional_parameters(param1 => 4, param2 => 5, param3 => 6);
-- named convention, second gets ommited
proc_optional_parameters(param1 => 7, param3 => 9);
-- named convention, different order
proc_optional_parameters(param3 => 12, param1 => 10, param2 => 11);
END;
CALL calling_procedure();
SELECT * FROM procedure_call_test_table;
COL1|
----+
1|
2|
3|
4|
5|
6|
7|
8|
9|
10|
11|
12|
Snowflake Scripting¶
-- Procedure with optional parameters
CREATE OR REPLACE PROCEDURE proc_optional_parameters
!!!RESOLVE EWI!!! /*** SSC-EWI-0002 - DEFAULT PARAMETERS MAY NEED TO BE REORDERED. SNOWFLAKE ONLY SUPPORTS DEFAULT PARAMETERS AT THE END OF THE PARAMETERS DECLARATIONS ***/!!!
(param1 INTEGER, param2 INTEGER DEFAULT 8, param3 INTEGER)
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 procedure_call_test_table
VALUES (:param1);
INSERT INTO procedure_call_test_table
VALUES (:param2);
INSERT INTO procedure_call_test_table
VALUES (:param3);
END;
$$;
CREATE OR REPLACE PROCEDURE calling_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CALL
-- positional convention
proc_optional_parameters(1, 2, 3);
CALL
-- named convention
proc_optional_parameters(param1 => 4, param2 => 5, param3 => 6);
CALL
-- named convention, second gets ommited
proc_optional_parameters(param1 => 7, param3 => 9);
CALL
-- named convention, different order
proc_optional_parameters(param1 => 10, param2 => 11, param3 => 12);
END;
$$;
CALL calling_procedure();
SELECT * FROM
procedure_call_test_table;
COL1|
----+
1|
2|
3|
4|
5|
6|
7|
8|
9|
10|
11|
12|
Known Issues¶
1. Calling Subprograms with default values is not supported¶
Snowflake does not support setting default values for parameters. So these will need to be filled into every call.
2. Named parameters are accepted, but not functionally equivalent¶
These parameters will not cause any compilation errors when ran in Snowflake; however, calls still place them in a positional manner. For this reason, the order of these parameters needs to be checked. SnowConvert does not support checking nor reordering these parameters.
3. Calling Subprograms with Out Parameters is not supported¶
Snowflake does not have support for parameter modes, however, a solution is being implemented to emulate their functionality. To get more information about the transformation for output parameters please go to the following article Output Parameters.
Related EWIs¶
SSC-EWI-0002: Default Parameters May Need To Be Reordered.
SSC-FDM-0007: Element with missing dependencies.
RAISE¶
Description¶
The RAISE
statement explicitly raises an exception.
Outside an exception handler, you must specify the exception name. Inside an exception handler, if you omit the exception name, the RAISE
statement reraises the current exception.(Oracle PL/SQL Language Reference Raise Statement)
The statement is fully supported by Snowflake Scripting, but please take into account that there might be some differences when having some Commit and Rollback Statement.
RAISE <exception_name> ;
Snowflake Scripting has support for this statement.
RAISE <exception_name> ;
Sample Source Patterns¶
Simple exception throw¶
Oracle¶
CREATE OR REPLACE PROCEDURE simple_exception_throw_handle(param1 INTEGER)
IS
my_exception EXCEPTION;
my_other_exception EXCEPTION;
BEGIN
IF param1 > 0
THEN RAISE my_exception;
END IF;
EXCEPTION
WHEN my_exception THEN
IF param1 = 1
THEN RAISE;
END IF;
RAISE my_other_exception;
END;
--Completes without issue
CALL simple_exception_throw_handle(0);
--Throws my_exception
CALL simple_exception_throw_handle(1);
--Throws my_exception, catches then raises second my_other_exception
CALL simple_exception_throw_handle(2);
Call completed.
-----------------------------------------------------------------------
Error starting at line : 31 in command -
CALL simple_exception_throw_handle(1)
Error report -
ORA-06510: PL/SQL: unhandled user-defined exception
ORA-06512: at "SYSTEM.SIMPLE_EXCEPTION_THROW_HANDLE", line 12
ORA-06512: at "SYSTEM.SIMPLE_EXCEPTION_THROW_HANDLE", line 7
ORA-06512: at line 1
06510. 00000 - "PL/SQL: unhandled user-defined exception"
*Cause: A user-defined exception was raised by PL/SQL code, but
not handled.
*Action: Fix the problem causing the exception or write an exception
handler for this condition. Or you may need to contact your
application administrator or DBA.
-----------------------------------------------------------------------
Error starting at line : 33 in command -
CALL simple_exception_throw_handle(2)
Error report -
ORA-06510: PL/SQL: unhandled user-defined exception
ORA-06512: at "SYSTEM.SIMPLE_EXCEPTION_THROW_HANDLE", line 14
ORA-06510: PL/SQL: unhandled user-defined exception
ORA-06512: at "SYSTEM.SIMPLE_EXCEPTION_THROW_HANDLE", line 7
ORA-06512: at line 1
06510. 00000 - "PL/SQL: unhandled user-defined exception"
*Cause: A user-defined exception was raised by PL/SQL code, but
not handled.
*Action: Fix the problem causing the exception or write an exception
handler for this condition. Or you may need to contact your
application administrator or DBA.
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE simple_exception_throw_handle (param1 INTEGER)
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
my_exception EXCEPTION;
my_other_exception EXCEPTION;
BEGIN
IF (:param1 > 0) THEN
RAISE my_exception;
END IF;
EXCEPTION
WHEN my_exception THEN
IF (:param1 = 1) THEN
RAISE;
END IF;
RAISE my_other_exception;
END;
$$;
--Completes without issue
CALL simple_exception_throw_handle(0);
--Throws my_exception
CALL simple_exception_throw_handle(1);
--Throws my_exception, catches then raises second my_other_exception
CALL simple_exception_throw_handle(2);
Call Completed
-----------------------------------------------------------------------
Uncaught exception of type 'MY_EXCEPTION' on line 7 at position 9
-----------------------------------------------------------------------
Uncaught exception of type 'MY_OTHER_EXCEPTION' on line 14 at position 9
Known Issues¶
No issues were found.
Related EWIs¶
No related EWIs.
RAISE_APPICATION_ERROR¶
General description¶
The procedure RAISE_APPLICATION_ERROR
lets you issue user-defined ORA-
error messages from stored subprograms. That way, you can report errors to your application and avoid returning unhandled exceptions (Oracle documentation
).
Oracle syntax¶
raise_application_error(
error_number, message[, {TRUE | FALSE}]);
Note
The error_number
is a negative integer in the range -20000 .. -20999 and message
is a character string up to 2048 bytes long.
If the optional third parameter is TRUE, the error is placed on the stack of previous errors. If the parameter is FALSE (the default), the error replaces all previous errors.
The equivalent statement in Snowflake is the RAISE clause, nevertheless, it is required to declare the user-defined exception as a variable before calling the RAISE statement for it.
Snowflake Syntax¶
<exception_name> EXCEPTION [ ( <exception_number> , '<exception_message>' ) ] ;
Note
For more information review the following Snowflake documentation.
Sample Source Patterns¶
1. Exception in functions without declaring section¶
In this scenario, the function without a declaring section is translated to a procedure with the exception declaration. Please note that:
The exception variable name is declared in upper case.
The exception variable name is based on the description and an ending is composed of an exception code name followed by a consecutive number.
The declaring section is created even though the initial function or procedure does not contain it.
Oracle
CREATE OR REPLACE FUNCTION TEST(
SAMPLE_A IN NUMBER DEFAULT NULL,
SAMPLE_B IN NUMBER DEFAULT NULL
)
RETURN NUMBER
AS
BEGIN
raise_application_error(-20001, 'First exception message', FALSE);
raise_application_error(-20002, 'Second exception message');
RETURN 1;
END TEST;
ORA-20001: First exception message
Snowflake
--** SSC-FDM-0029 - USER DEFINED FUNCTION WAS TRANSFORMED TO SNOWFLAKE PROCEDURE **
CREATE OR REPLACE PROCEDURE TEST(
SAMPLE_A NUMBER(38, 18) DEFAULT NULL,
SAMPLE_B NUMBER(38, 18) DEFAULT NULL
)
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
FIRST_EXCEPTION_MESSAGE_EXCEPTION_CODE_0 EXCEPTION (-20001, 'FIRST EXCEPTION MESSAGE');
SECOND_EXCEPTION_MESSAGE_EXCEPTION_CODE_1 EXCEPTION (-20002, 'SECOND EXCEPTION MESSAGE');
BEGIN
--** SSC-FDM-OR0011 - ADD TO STACK OF ERRORS IS NOT SUPPORTED, BOOLEAN ARGUMENT FALSE WAS REMOVED. **
RAISE FIRST_EXCEPTION_MESSAGE_EXCEPTION_CODE_0;
RAISE SECOND_EXCEPTION_MESSAGE_EXCEPTION_CODE_1;
RETURN 1;
END;
$$;
FIRST EXCEPTION MESSAGE
2. Exception code number outside limits¶
The following example shows the translation commented out in the procedure body. It is because the code is outside the applicable code limits in Snowflake. The solution is to change the exception code for an available code in the query section.
Oracle
CREATE OR REPLACE FUNCTION TEST(
SAMPLE_A IN NUMBER DEFAULT NULL,
SAMPLE_B IN NUMBER DEFAULT NULL
)
RETURN NUMBER
AS
BEGIN
raise_application_error(-20000, 'My exception message');
RETURN 1;
END TEST;
ORA-20000: My exception message
Snowflake
--** SSC-FDM-0029 - USER DEFINED FUNCTION WAS TRANSFORMED TO SNOWFLAKE PROCEDURE **
CREATE OR REPLACE PROCEDURE TEST(
SAMPLE_A NUMBER(38, 18) DEFAULT NULL,
SAMPLE_B NUMBER(38, 18) DEFAULT NULL
)
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
MY_EXCEPTION_MESSAGE_EXCEPTION_CODE_0 EXCEPTION (-20000, 'MY EXCEPTION MESSAGE');
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0099 - EXCEPTION CODE NUMBER EXCEEDS SNOWFLAKE SCRIPTING LIMITS ***/!!!
RAISE MY_EXCEPTION_MESSAGE_EXCEPTION_CODE_0;
RETURN 1;
END;
$$;
Invalid error code '-20,000'. Must be between -20,999 and -20,000
3. Exception stack functionality¶
The exception stack functionality is not supported in Snowflake and is removed from the exception declaration.
Oracle
CREATE OR REPLACE FUNCTION TEST(
SAMPLE_A IN NUMBER DEFAULT NULL,
SAMPLE_B IN NUMBER DEFAULT NULL
)
RETURN NUMBER
AS
BEGIN
raise_application_error(-20001, 'My exception message', TRUE);
RETURN 1;
END TEST;
ORA-20001: My exception message
Snowflake
--** SSC-FDM-0029 - USER DEFINED FUNCTION WAS TRANSFORMED TO SNOWFLAKE PROCEDURE **
CREATE OR REPLACE PROCEDURE TEST(
SAMPLE_A NUMBER(38, 18) DEFAULT NULL,
SAMPLE_B NUMBER(38, 18) DEFAULT NULL
)
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
MY_EXCEPTION_MESSAGE_EXCEPTION_CODE_0 EXCEPTION (-20001, 'MY EXCEPTION MESSAGE');
BEGIN
--** SSC-FDM-OR0011 - ADD TO STACK OF ERRORS IS NOT SUPPORTED, BOOLEAN ARGUMENT TRUE WAS REMOVED. **
RAISE MY_EXCEPTION_MESSAGE_EXCEPTION_CODE_0;
RETURN 1;
END;
$$;
MY EXCEPTION MESSAGE
4. Multiple exceptions with the same exception code¶
Multiple exceptions with the same can coexist in the declaring section and raise statements.
Oracle
CREATE OR REPLACE FUNCTION TEST(
SAMPLE_A IN NUMBER DEFAULT NULL,
SAMPLE_B IN NUMBER DEFAULT NULL
)
RETURN NUMBER
AS
BEGIN
IF TRUE THEN
raise_application_error(-20001, 'The first exception');
ELSE
raise_application_error(-20001, 'Other exception inside');
END IF;
RETURN 1;
END TEST;
ORA-20000: The first exception
Snowflake
--** SSC-FDM-0029 - USER DEFINED FUNCTION WAS TRANSFORMED TO SNOWFLAKE PROCEDURE **
CREATE OR REPLACE PROCEDURE TEST(
SAMPLE_A NUMBER(38, 18) DEFAULT NULL,
SAMPLE_B NUMBER(38, 18) DEFAULT NULL
)
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
THE_FIRST_EXCEPTION_EXCEPTION_CODE_0 EXCEPTION (-20001, 'THE FIRST EXCEPTION');
OTHER_EXCEPTION_INSIDE_EXCEPTION_CODE_1 EXCEPTION (-20001, 'OTHER EXCEPTION INSIDE');
BEGIN
IF (TRUE) THEN
RAISE THE_FIRST_EXCEPTION_EXCEPTION_CODE_0;
ELSE
RAISE OTHER_EXCEPTION_INSIDE_EXCEPTION_CODE_1;
END IF;
RETURN 1;
END;
$$;
THE FIRST EXCEPTION
Known Issues¶
SQLREM function may be reviewed.
Exception code number outside the applicable limits in Snowflake has to be changed to an available code exception.
Add to a stack of errors is not supported.
Related EWIs¶
SSC-EWI-OR0099: The exception code exceeds the Snowflake Scripting limit.
SSC-FDM-0029: User defined function was transformed to a Snowflake procedure.
SSC-FDM-OR0011: The boolean argument was removed because the “add to stack” options is not supported.
UDF CALL¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
As is widely acknowledged, non-scalar user-defined functions (UDFs) in Oracle are converted into Snowflake stored procedures to accommodate more intricate functionalities.
This transformation also alters the way the function is invoked, transitioning from a traditional function call to a stored procedure call.
For additional details regarding the invocation of stored procedures, refer to the documentation accessible here: PROCEDURE CALL.
Sample Source Patterns¶
Note
Consider the next function and tables for the examples below.
CREATE OR REPLACE FUNCTION sum_to_varchar_function(p_number1 IN NUMBER, p_number2 IN NUMBER)
RETURN VARCHAR
IS
result VARCHAR(100);
BEGIN
result := TO_CHAR(p_number1 + p_number2);
RETURN result;
END sum_to_varchar_function;
CREATE TABLE example_table (
id NUMBER,
column1 NUMBER
);
INSERT INTO example_table VALUES (1, 15);
CREATE TABLE result_table (
id NUMBER,
result_col VARCHAR(100)
);
CREATE OR REPLACE FUNCTION sum_to_varchar_function (p_number1 NUMBER(38, 18), p_number2 NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "11/14/2024", "domain": "test" }}'
AS
$$
WITH declaration_variables_cte1 AS
(
SELECT
TO_CHAR(p_number1 + p_number2) AS
result
)
SELECT
result
FROM
declaration_variables_cte1
$$;
CREATE OR REPLACE TABLE example_table (
id NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
column1 NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "11/14/2024", "domain": "test" }}'
;
INSERT INTO example_table
VALUES (1, 15);
CREATE OR REPLACE TABLE result_table (
id NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
result_col VARCHAR(100)
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "11/14/2024", "domain": "test" }}'
;
UDF Call¶
Oracle¶
CREATE OR REPLACE PROCEDURE procedure_calling_function(param1 IN NUMBER)
IS
result_value VARCHAR(200);
BEGIN
result_value := sum_to_varchar_function(3, param1);
INSERT INTO result_table VALUES (1, result_value);
END;
BEGIN
procedure_calling_function(5);
END;
ID RESULT_COL
1 8
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE procedure_calling_function (param1 NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
result_value VARCHAR(200);
BEGIN
result_value := sum_to_varchar_function(3, :param1) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'sum_to_varchar_function' NODE ***/!!!;
INSERT INTO result_table
VALUES (1, :result_value);
END;
$$;
DECLARE
call_results VARIANT;
BEGIN
CALL
procedure_calling_function(5);
RETURN call_results;
END;
ID RESULT_COL
1 8
UDF Call within a query¶
When a function call is embedded within a query, the invocation process becomes more intricate due to Snowflake’s limitation of not being able to call procedures directly within queries. To overcome this limitation, the procedure invocation is moved outside the query, and the result is assigned to a variable. This variable is then referenced within the query, thereby achieving functional equivalence. This approach allows for the execution of more complex behaviors within Snowflake queries while adhering to the procedural constraints.
Oracle¶
CREATE OR REPLACE PROCEDURE procedure_calling_function(param1 IN NUMBER)
IS
result_value VARCHAR(200);
result_value2 VARCHAR(200);
BEGIN
SELECT
sum_to_varchar_function(1, param1) AS result_column,
sum_to_varchar_function(2, param1) AS result_column2
INTO result_value, result_value2
FROM example_table ext;
INSERT INTO result_table VALUES (1, result_value);
INSERT INTO result_table VALUES (2, result_value2);
END;
BEGIN
procedure_calling_function(5);
END;
ID RESULT_COL
1 6
2 7
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE procedure_calling_function (param1 NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
result_value VARCHAR(200);
result_value2 VARCHAR(200);
BEGIN
SELECT
sum_to_varchar_function(1, :param1) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'sum_to_varchar_function' NODE ***/!!! AS result_column,
sum_to_varchar_function(2, :param1) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'sum_to_varchar_function' NODE ***/!!! AS result_column2
INTO
:result_value,
:result_value2
FROM
example_table ext;
INSERT INTO result_table
VALUES (1, :result_value);
INSERT INTO result_table
VALUES (2, :result_value2);
END;
$$;
DECLARE
call_results VARIANT;
BEGIN
CALL
procedure_calling_function(5);
RETURN call_results;
END;
ID RESULT_COL
1 6
2 7
Known Issues¶
1. Unsupported Usage of UDFs in Queries with Query Dependencies¶
When calling User-Defined Functions (UDFs) within queries with query dependencies, scenarios involving embedded functions with columns as arguments are not supported. This limitation arises because the column values cannot be accessed from outside the query. Examples of unsupported scenarios include:
BEGIN
SELECT
sum_to_varchar_function(ext.col1, ext.col2) -- columns as arguments not supported
INTO
result_value
FROM example_table ext;
END;
The supported scenarios include function calls with other types of arguments such as literal values, external variables, or parameters. For instance:
BEGIN
SELECT
sum_to_varchar_function(100, param1)
INTO
result_value
FROM example_table ext;
END;
In the supported scenarios, the function can effectively be migrated.
Related EWIs¶
SSC-EWI-0073: Pending Functional Equivalence Review.
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-0029: User defined function was transformed to a Snowflake procedure.
WHILE¶
Description¶
The WHILE
LOOP
statement runs one or more statements while a condition is TRUE
.
(Oracle PL/SQL Language Reference WHILE Statement)
WHILE boolean_expression
LOOP statement... END LOOP [ label ] ;
WHILE ( <condition> ) { DO | LOOP }
<statement>;
[ <statement>; ... ]
END { WHILE | LOOP } [ <label> ] ;
Oracle WHILE
behavior can also be modified by using the statements:
Sample Source Patterns¶
While simple case¶
This case is functionally equivalent.
Oracle
CREATE TABLE while_testing_table
(
iterator VARCHAR2(5)
);
CREATE OR REPLACE PROCEDURE while_procedure
IS
I NUMBER := 1;
J NUMBER := 10;
BEGIN
WHILE I <> J LOOP
INSERT INTO while_testing_table VALUES(TO_CHAR(I));
I := I+1;
END LOOP;
END;
CALL while_procedure();
SELECT * FROM while_testing_table;
ITERATOR|
--------+
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
9 |
Snowflake Scripting
CREATE OR REPLACE TABLE while_testing_table
(
iterator VARCHAR(5)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE while_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
I NUMBER(38, 18) := 1;
J NUMBER(38, 18) := 10;
BEGIN
WHILE (:I <> :J) LOOP
INSERT INTO while_testing_table
VALUES(TO_CHAR(:I));
I := :I +1;
END LOOP;
END;
$$;
CALL while_procedure();
SELECT * FROM
while_testing_table;
ITERATOR|
--------+
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
9 |
Known Issues
No issues were found.
Related EWIs
No related EWIs.
CURSOR
Description
Note
For more information regarding the Cursor declaration, check here.
This section covers the Translation Reference for Oracle Explicit Cursor. For Oracle Cursor Variables there is no equivalent in Snowflake Scripting.
Note
Some parts in the output code are omitted for clarity reasons.
Cursors are pointers that allow users to iterate through query results. For more information on Oracle Cursors check here.
Cursor Definition
CURSOR cursor
[ ( cursor_parameter_dec [, cursor_parameter_dec ]... )]
[ RETURN rowtype] IS select_statement ;
Cursor Open
OPEN cursor [ ( cursor_parameter [ [,] actual_cursor_parameter ]... ) ] ;
Cursor Fetch
FETCH { cursor | cursor_variable | :host_cursor_variable }
{ into_clause | bulk_collect_into_clause [ LIMIT numeric_expression ] } ;
Cursor Close
CLOSE { cursor | cursor_variable | :host_cursor_variable } ;
Cursor Attributes
named_cursor%{ ISOPEN | FOUND | NOTFOUND | ROWCOUNT }
Cursor FOR Loop
[ FOR record IN
{ cursor [ ( cursor_parameter_dec
[ [,] cursor_parameter_dec ]... )]
| ( select_statement )
}
LOOP statement... END LOOP [label] ;
Snowflake Scripting has support for cursors, however, they have fewer functionalities compared to Oracle. To check more information regarding these cursors, check here.
Cursor Declaration
<cursor_name> CURSOR FOR <query>
Cursor Open
OPEN <cursor_name> [ USING (bind_variable_1 [, bind_variable_2 ...] ) ] ;
Cursor Fetch
FETCH <cursor_name> INTO <variable> [, <variable> ... ] ;
Cursor Close
CLOSE <cursor_name> ;
Cursor FOR Loop
FOR <row_variable> IN <cursor_name> DO
statement;
[ statement; ... ]
END FOR [ <label> ] ;
Sample Source Patterns¶
1. Basic cursor example¶
CREATE OR REPLACE PROCEDURE basic_cursor_sample AS
var1 VARCHAR(20);
CURSOR cursor1 IS SELECT region_name FROM hr.regions ORDER BY region_name;
BEGIN
OPEN cursor1;
FETCH cursor1 INTO var1;
CLOSE cursor1;
END;
CREATE OR REPLACE PROCEDURE basic_cursor_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
var1 VARCHAR(20);
cursor1 CURSOR
FOR
SELECT region_name FROM
hr.regions
ORDER BY region_name;
BEGIN
OPEN cursor1;
FETCH cursor1 INTO
:var1;
CLOSE cursor1;
END;
$$;
2. Explicit Cursor For Loop¶
CREATE OR REPLACE PROCEDURE explicit_cursor_for_sample AS
CURSOR cursor1 IS SELECT region_name FROM hr.regions ORDER BY region_name;
BEGIN
FOR r1 IN cursor1 LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE explicit_cursor_for_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor1 CURSOR
FOR
SELECT region_name FROM
hr.regions
ORDER BY region_name;
BEGIN
OPEN cursor1;
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR r1 IN cursor1 DO
NULL;
END FOR;
CLOSE cursor1;
END;
$$;
3. Implicit Cursor For Loop¶
CREATE OR REPLACE PROCEDURE implicit_cursor_for_sample AS
BEGIN
FOR r1 IN (SELECT region_name FROM hr.regions ORDER BY region_name) LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE implicit_cursor_for_sample ()
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 region_name FROM
hr.regions
ORDER BY region_name);
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR r1 IN temporary_for_cursor_0 DO
NULL;
END FOR;
END;
$$;
4. Parameterized Cursor¶
You can use “?” In the filter condition of the cursor at the declaration section define the bind variable. While opening the cursor we can add the additional syntax “USING <bind_variable_1 >” to pass the bind variable.
Below are some examples of scenarios that can occur in the use of parameters in cursors:
4.1 Basic Cursor Parameterized Example¶
CREATE OR REPLACE PROCEDURE parameterized_cursor_for_sample AS
CURSOR cursor1 (low number, high IN number) IS
SELECT region_name FROM hr.regions WHERE region_id BETWEEN low AND high;
BEGIN
OPEN cursor1(3,5);
CLOSE cursor1;
END;
CREATE OR REPLACE PROCEDURE parameterized_cursor_for_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor1 CURSOR
FOR
SELECT region_name FROM
hr.regions
WHERE region_id BETWEEN ? AND ?;
BEGIN
OPEN cursor1 USING (3, 5);
CLOSE cursor1;
END;
$$;
4.2 Parameterized Cursors With Multiple Sending Parameters¶
CREATE OR REPLACE PROCEDURE parameterized_cursor_for_sample AS
CURSOR cursor1 (low number DEFAULT 2, high IN number DEFAULT 7) IS
SELECT region_name FROM hr.regions
WHERE region_id BETWEEN low AND high OR low < 0;
BEGIN
OPEN cursor1(3,5);
OPEN cursor1(3);
OPEN cursor1;
OPEN cursor1(high => 15, low => 5);
OPEN cursor1(high => 15);
CLOSE cursor1;
END;
CREATE OR REPLACE PROCEDURE parameterized_cursor_for_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor1 CURSOR
FOR
SELECT region_name FROM
hr.regions
WHERE region_id BETWEEN ? AND ?
OR ? < 0;
BEGIN
OPEN cursor1 USING (3, 5, 3);
OPEN cursor1 USING (3, 7, 3);
OPEN cursor1 USING (2, 7, 2);
OPEN cursor1 USING (5, 15, 5);
OPEN cursor1 USING (2, 15, 2);
CLOSE cursor1;
END;
$$;
4.3 Parameterized Cursors With Use Of Procedure Parameters In Query¶
CREATE OR REPLACE PROCEDURE parameterized_cursor_for_sample (high_param number) AS
CURSOR cursor1 (low number DEFAULT 2) IS
SELECT region_name FROM hr.regions
WHERE region_id BETWEEN low AND high_param;
BEGIN
OPEN cursor1(3);
CLOSE cursor1;
END;
CALL parameterized_cursor_for_sample(5);
CREATE OR REPLACE PROCEDURE parameterized_cursor_for_sample (high_param NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor1 CURSOR
FOR
SELECT region_name FROM
hr.regions
WHERE region_id BETWEEN ? AND ?;
BEGIN
OPEN cursor1 USING (3, high_param);
CLOSE cursor1;
END;
$$;
CALL parameterized_cursor_for_sample(5);
5. Using Cursors In Fetch And For Loop¶
Cursors can be controlled through the use of the FOR statement, allowing each and every record of a cursor to be processed while the FETCH statement puts, record by record, the values returned by the cursor into a set of variables, which may be PLSQL records
5.1 Cursors For Loop¶
CREATE OR REPLACE PROCEDURE p_cursors_for_loop AS
datePlusOne TIMESTAMP;
CURSOR c_product(low number, high number) IS
SELECT name, price, create_on FROM products WHERE price BETWEEN low AND high;
BEGIN
FOR record_product IN c_product(3,5)
LOOP
datePlusOne := record_product.create_on + 1;
INSERT INTO sold_items values(record_product.name, record_product.price, datePlusOne);
END LOOP;
END;
CREATE OR REPLACE PROCEDURE p_cursors_for_loop ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
datePlusOne TIMESTAMP(6);
c_product CURSOR
FOR
SELECT
OBJECT_CONSTRUCT('NAME', name, 'PRICE', price, 'CREATE_ON', create_on) sc_cursor_record FROM
products
WHERE price BETWEEN ? AND ?;
BEGIN
OPEN c_product USING (3, 5);
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR record_product IN c_product DO
LET record_product OBJECT := record_product.sc_cursor_record;
datePlusOne :=
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '+' MAY NOT BEHAVE CORRECTLY BETWEEN unknown AND Number ***/!!!
record_product.CREATE_ON + 1;
INSERT INTO sold_items
SELECT
:record_product:NAME,
:record_product:PRICE,
:datePlusOne;
END FOR;
CLOSE c_product;
END;
$$;
5.2 Cursors Fetch¶
CREATE OR REPLACE PROCEDURE p_cursors_fetch AS
record_product products%rowtype;
CURSOR c_product(low number, high number) IS
SELECT * FROM products WHERE price BETWEEN low AND high;
BEGIN
OPEN c_product(3,5);
LOOP
FETCH c_product INTO record_product;
EXIT WHEN c_product%notfound;
INSERT INTO sold_items VALUES (record_product.name, record_product.price);
INSERT INTO sold_items VALUES record_product;
END LOOP;
CLOSE c_product;
END;
CREATE OR REPLACE PROCEDURE p_cursors_fetch ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
record_product OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWTYPE DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
c_product CURSOR
FOR
SELECT
OBJECT_CONSTRUCT( *) sc_cursor_record FROM
products
WHERE price BETWEEN ? AND ?;
BEGIN
OPEN c_product USING (3, 5);
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH c_product INTO
:record_product;
IF (record_product IS NULL) THEN
EXIT;
END IF;
INSERT INTO sold_items
SELECT
:record_product:NAME,
:record_product:PRICE;
INSERT INTO sold_items
SELECT
null !!!RESOLVE EWI!!! /*** SSC-EWI-OR0002 - COLUMNS FROM EXPRESSION products%rowtype NOT FOUND ***/!!!;
END LOOP;
CLOSE c_product;
END;
$$;
Known Issues¶
1. RETURN clause is not supported in Snowflake Scripting Cursor Declaration¶
The Cursor Declaration for Snowflake Scripting does not include this clause. It can be removed from the Oracle Cursor definition to get functional equivalence.
2. OPEN statement cannot pass values for declared arguments¶
Even though arguments can be declared for a cursor, their values cannot be assigned in Snowflake Scripting. The best alternative is to use the USING
clause with bind variables.
3. FETCH statement cannot use records¶
Snowflake Scripting does not support records. However, it is possible to migrate them using the OBJECT data type and the OBJECT_CONSTRUCT() method. For more information please see the Record Type Definition Section.
4. FETCH BULK COLLECT INTO clause is not supported in Snowflake Scripting¶
Snowflake Scripting does not support the BULK COLLECT INTO clause. However, it is possible to use ARRAY_AGG along with a temporal table to construct a new variable with the data corresponding to the Cursor information. For more information please see the Collection Bulk Operations Section.
5. Cursor attributes do not exist in Snowflake Scripting¶
Oracle cursors have different attributes that allow the user to check their status like if it is opened or the amount of fetched rows, however, these attributes regarding the cursor status do not exist in Snowflake Scripting.
6. The cursor’s query does not have access to the procedure’s variables and parameters¶
In Oracle, the query in the cursor declaration has access to procedure variables and parameters but in Snowflake Scripting, it does not. The alternative to this is to use the USING
clause with bind variables. For more information check this section.
7. %NOTFOUND attribute is not supported in Snowflake Scripting Cursor¶
In Oracle can be used, before the first fetch from an open cursor, cursor_name%NOTFOUND returns TRUE if the last fetch failed to return a row, or FALSE if the last fetch returned a row. Snowflake Scripting does not support the use of this attribute instead it can be validated if the variable assigned to the cursor result contains values
Related EWIs¶
SSC-EWI-0036: Data type converted to another data type.
SSC-EWI-OR0002: Columns from expression not found.
SSC-EWI-OR0036: Types resolution issues, the arithmetic operation may not behave correctly between string and date.
SSC-PRF-0003: Fetch inside a loop is considered a complex pattern, this could degrade Snowflake performance.
SSC-PRF-0004: This statement has usages of cursor for loop.
CURSOR DECLARATION¶
Note
Non-relevant statement.
Warning
Notice that this statement isremoved from the migrationbecause it is a non-relevant syntax. It means that it is not required in Snowflake.
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
This section explains the translation of the declaration of cursors in Oracle. For more information review the following documentation about procedures and cursors in Oracle.
Sample Source Patterns¶
CURSOR DECLARATION¶
Notice that in this example the CURSOR
statement has been deleted. This is a non-relevant syntax in the transformation targeted to Snowflake.
CREATE PROCEDURE PROC_COLLECTIONS
AS
CURSOR C2 RETURN T1%TYPE;
BEGIN
NULL;
END
CREATE OR REPLACE PROCEDURE PROC_COLLECTIONS ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
NULL;
END;
$$;
Known Issues ¶
No issues were found.
Related EWIs ¶
No related EWIs.
Cursor Variables¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
A cursor variable is like an explicit cursor that is not limited to one query.
(Oracle PL/SQL Language Reference Cursor Variable Declaration)
Ref cursor type definition
TYPE type IS REF CURSOR
[ RETURN
{ {db_table_or_view | cursor | cursor_variable}%ROWTYPE
| record%TYPE
| record_type
| ref_cursor_type
}
] ;
Cursor variable declaration
cursor_variable type;
OPEN FOR statement
OPEN { cursor_variable | :host_cursor_variable}
FOR select_statement [ using_clause ] ;
Warning
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¶
CREATE OR REPLACE PROCEDURE procedure1
AS
query1 VARCHAR(200) := 'SELECT 123 FROM dual';
cursor_var SYS_REFCURSOR;
BEGIN
OPEN cursor_var FOR query1;
CLOSE cursor_var;
END;
CREATE OR REPLACE PROCEDURE procedure1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
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 CURSOR
FOR
cursor_var_res;
OPEN cursor_var;
CLOSE cursor_var;
END;
$$;
2. OPEN FOR statement with dynamic SQL inside a string literal.¶
CREATE OR REPLACE PROCEDURE procedure2
AS
cursor_var SYS_REFCURSOR;
BEGIN
OPEN cursor_var FOR 'SELECT 123 FROM dual';
CLOSE cursor_var;
END;
CREATE OR REPLACE PROCEDURE procedure2 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
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 CURSOR
FOR
cursor_var_res;
OPEN cursor_var;
CLOSE cursor_var;
END;
$$;
3. OPEN FOR statement with SELECT statement¶
CREATE OR REPLACE PROCEDURE procedure3
AS
cursor_var SYS_REFCURSOR;
BEGIN
OPEN cursor_var FOR SELECT 123 FROM dual;
CLOSE cursor_var;
END;
CREATE OR REPLACE PROCEDURE procedure3 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor_var_res RESULTSET;
BEGIN
LET cursor_var CURSOR
FOR
SELECT 123 FROM dual;
OPEN cursor_var;
CLOSE cursor_var;
END;
$$;
4. Cursor Variable declared with REF CURSOR type¶
CREATE OR REPLACE PROCEDURE procedure4
AS
TYPE cursor_ref_type1 IS REF CURSOR;
query1 VARCHAR(200) := 'SELECT 123 FROM dual';
cursor_var cursor_ref_type1;
BEGIN
OPEN cursor_var FOR query1;
CLOSE cursor_var;
END;
CREATE OR REPLACE PROCEDURE procedure4 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
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 CURSOR
FOR
cursor_var_res;
OPEN cursor_var;
CLOSE cursor_var;
END;
$$;
5. OPEN FOR statement with USING clause¶
CREATE OR REPLACE PROCEDURE procedure5
AS
query1 VARCHAR(200) := 'SELECT col1 FROM cursortable1 WHERE col1 = :a';
column_filter INTEGER := 1;
cursor_var SYS_REFCURSOR;
BEGIN
OPEN cursor_var FOR query1 USING column_filter;
CLOSE cursor_var;
END;
CREATE OR REPLACE PROCEDURE procedure5 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
query1 VARCHAR(200) := 'SELECT col1 FROM
cursortable1
WHERE 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 CURSOR
FOR
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.
PARAMETRIZED CURSOR¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
Oracle supports parameters for cursors that are declared. However, Snowflake Scripting does not support this feature, so the declaration and the usage of the cursor are not possible.
Example Code¶
Input Code Oracle:¶
CREATE OR REPLACE PROCEDURE parametrized_cursor_sample AS
CURSOR cursor1(param1 number) IS SELECT region_name FROM hr.regions where region_id = param1 ORDER BY region_name;
var1 integer;
BEGIN
OPEN cursor1(123);
FETCH cursor1 INTO var1;
CLOSE cursor1;
FOR r1 IN cursor1(456) LOOP
NULL;
END LOOP;
END;
Output Code:¶
CREATE OR REPLACE PROCEDURE parametrized_cursor_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor1 CURSOR
FOR
SELECT
OBJECT_CONSTRUCT('REGION_NAME', region_name) sc_cursor_record FROM
hr.regions
where region_id = ?
ORDER BY region_name;
var1 integer;
BEGIN
OPEN cursor1 USING (123);
FETCH cursor1 INTO
:var1;
CLOSE cursor1;
OPEN cursor1 USING (456);
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR r1 IN cursor1 DO
LET r1 OBJECT := r1.sc_cursor_record;
NULL;
END FOR;
CLOSE cursor1;
END;
$$;
Recommendations¶
Try using bindings for the query in the cursor and open the cursor with the
USING
clause. Keep in mind that a parameter that is used multiple times on a single cursor may require passing the variable multiple times in theUSING
clause.
CREATE OR REPLACE PROCEDURE PUBLIC.parametrized_cursor_sample_fixed ()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
var1 STRING;
cursor1 CURSOR FOR SELECT region_name FROM hr.regions where region_id = ? ORDER BY region_name;
BEGIN
NULL;
OPEN cursor1 USING (1);
FETCH cursor1 INTO var1;
CLOSE cursor1;
OPEN cursor1 USING (2);
FOR r1 IN cursor1 DO
NULL;
END FOR;
CLOSE cursor1;
END;
$$;
Manually change the cursor to use bindings.
If you need more support, you can email us at snowconvert-support@snowflake.com
Related EWIs¶
SSC-PRF-0004: This statement has usages of cursor for loop.
Workaround for cursors using parameters or procedure variables¶
Description¶
This section describes how to simulate the usage of cursor parameters and procedure variables inside the query of a cursor. The name of the variables or parameters is replaced with bindings using the ?
sign. Then, when the cursor is opened, the values should be passed with the USING
clause.
Note
Some parts in the output code are omitted for clarity reasons.
Cursor with local variables¶
Use bindings for the query in the cursor for variable or procedure parameter used and open the cursor with the USING
clause.
CREATE OR REPLACE PROCEDURE oracle_cursor_sample
AS
like_value VARCHAR(255);
CURSOR c1 IS SELECT region_name FROM hr.regions WHERE region_name LIKE like_value ORDER BY region_name;
r_name VARCHAR(255);
BEGIN
like_value := 'E%';
OPEN c1;
FETCH c1 INTO r_name;
CLOSE c1;
like_value := 'A%';
FOR r1 IN c1 LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE oracle_cursor_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
like_value VARCHAR(255);
c1 CURSOR
FOR
SELECT region_name FROM
hr.regions
WHERE region_name LIKE ?
ORDER BY region_name;
r_name VARCHAR(255);
BEGIN
like_value := 'E%';
OPEN c1 USING (like_value);
FETCH c1 INTO
:r_name;
CLOSE c1;
like_value := 'A%';
OPEN c1;
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR r1 IN c1 DO
NULL;
END FOR;
CLOSE c1;
END;
$$;
Cursor with parameters¶
Use bindings for the query in the cursor for each parameter used and open the cursor with the USING
clause. Keep in mind that a parameter that is used multiple times on a single cursor may require passing the variable multiple times in the USING
clause.
CREATE OR REPLACE PROCEDURE parametrized_cursor_sample AS
CURSOR cursor1(param1 number) IS SELECT region_name FROM hr.regions where region_id = param1 ORDER BY region_name;
var1 integer;
BEGIN
OPEN cursor1(123);
FETCH cursor1 INTO var1;
CLOSE cursor1;
FOR r1 IN cursor1(456) LOOP
NULL;
END LOOP;
END;
CREATE OR REPLACE PROCEDURE parametrized_cursor_sample ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
cursor1 CURSOR
FOR
SELECT
OBJECT_CONSTRUCT('REGION_NAME', region_name) sc_cursor_record FROM
hr.regions
where region_id = ?
ORDER BY region_name;
var1 integer;
BEGIN
OPEN cursor1 USING (123);
FETCH cursor1 INTO
:var1;
CLOSE cursor1;
OPEN cursor1 USING (456);
--** SSC-PRF-0004 - THIS STATEMENT HAS USAGES OF CURSOR FOR LOOP **
FOR r1 IN cursor1 DO
LET r1 OBJECT := r1.sc_cursor_record;
NULL;
END FOR;
CLOSE cursor1;
END;
$$;
Related EWIs¶
SSC-PRF-0004: This statement has usages of cursor for loop
CREATE FUNCTION¶
Description¶
Note
Some parts in the output code are omitted for clarity reasons.
A stored function (also called a user function or user-defined function) is a set of PL/SQL statements you can call by name. Stored functions are very similar to procedures, except that a function returns a value to the environment in which it is called. User functions can be used as part of a SQL expression.
A call specification declares a Java method or a third-generation language (3GL) routine so that it can be called from PL/SQL. You can also use the CALL
SQL statement to call such a method or routine. The call specification tells Oracle Database which Java method, or which named function in which shared library, to invoke when a call is made. It also tells the database what type conversions to make for the arguments and return value. Oracle SQL Language Reference Create Function.
Oracle Syntax¶
For more information regarding Oracle Create Function, check here.
CREATE [ OR REPLACE ] [ EDITIONABLE | NONEDITIONABLE ]
FUNCTION
[ schema. ] function_name
[ ( parameter_declaration [, parameter_declaration]... ) ] RETURN datatype
[ sharing_clause ]
[ { invoker_rights_clause
| accessible_by_clause
| default_collation_clause
| deterministic_clause
| parallel_enable_clause
| result_cache_clause
| aggregate_clause
| pipelined_clause
| sql_macro_clause
}...
]
{ IS | AS } { [ declare_section ]
BEGIN statement ...
[ EXCEPTION exception_handler [ exception_handler ]... ]
END [ name ] ;
|
{ java_declaration | c_declaration } } ;
Snowflake Syntax¶
Snowflake allows 3 different languages in their user-defined functions:
SQL
JavaScript
Java
For now, SnowConvert will support only SQL
and JavaScript
as target languages.
For more information regarding Snowflake Create Function, check here.
Note
SQL user-defined functions only support one query as their body. They can read from the database but are not allowed to write to or modify it (Scalar SQL UDFs).
CREATE [ OR REPLACE ] [ SECURE ] FUNCTION <name> ( [ <arg_name> <arg_data_type> ] [ , ... ] )
RETURNS { <result_data_type> | TABLE ( <col_name> <col_data_type> [ , ... ] ) }
[ [ NOT ] NULL ]
[ { CALLED ON NULL INPUT | { RETURNS NULL ON NULL INPUT | STRICT } } ]
[ VOLATILE | IMMUTABLE ]
[ COMMENT = '<string_literal>' ]
AS '<function_definition>'
Note
JavaScript user-defined functions allow multiple statements in their bodies but cannot perform queries to the database. (Scalar JavaScript UDFs).
CREATE [ OR REPLACE ] [ SECURE ] FUNCTION <name> ( [ <arg_name> <arg_data_type> ] [ , ... ] )
RETURNS { <result_data_type> | TABLE ( <col_name> <col_data_type> [ , ... ] ) }
[ [ NOT ] NULL ]
LANGUAGE JAVASCRIPT
[ { CALLED ON NULL INPUT | { RETURNS NULL ON NULL INPUT | STRICT } } ]
[ VOLATILE | IMMUTABLE ]
[ COMMENT = '<string_literal>' ]
AS '<function_definition>'
Sample Source Patterns¶
Sample auxiliary data¶
Note
This code was executed for a better understanding of the examples:
CREATE TABLE table1 (col1 int, col2 int, col3 varchar2(250), col4 varchar2(250), col5 date);
INSERT INTO table1 VALUES (1, 11, 'val1_1', 'val1_2', TO_DATE('2004/05/03', 'yyyy-MM-dd'));
INSERT INTO table1 VALUES (2, 22, 'val2_1', 'val2_2', TO_DATE('2014/05/03', 'yyyy-MM-dd'));
INSERT INTO table1 VALUES (3, 33, 'val3_1', 'val3_2', TO_DATE('2024/05/03', 'yyyy-MM-dd'));
CREATE OR REPLACE TABLE table1 (col1 int,
col2 int,
col3 VARCHAR(250),
col4 VARCHAR(250),
col5 TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "07/25/2024" }}'
;
INSERT INTO table1
VALUES (1, 11, 'val1_1', 'val1_2', TO_DATE('2004/05/03', 'yyyy-MM-dd'));
INSERT INTO table1
VALUES (2, 22, 'val2_1', 'val2_2', TO_DATE('2014/05/03', 'yyyy-MM-dd'));
INSERT INTO table1
VALUES (3, 33, 'val3_1', 'val3_2', TO_DATE('2024/05/03', 'yyyy-MM-dd'));
Known Issues¶
No issues were found.
Related EWIS¶
SSC-FDM-OR0042: Date Type Transformed To Timestamp Has A Different Behavior
Cursor for a return variable¶
Note
Some parts in the output code are omitted for clarity reasons.
This pattern defines a function in Oracle PL/SQL that uses a cursor to fetch a single value and return it.
Components:
Function Declaration:
CREATE FUNCTION functionName(parameters) RETURN returnType
Declares the function with input parameters and the return type.
Variable Declarations:
Declares variables, including the return variable.
Cursor Declaration:
CURSOR cursorName IS SELECT singleColumn FROM ... WHERE ... [AND col1 = localVar1];
Defines a cursor to select a single column from a table with optional filtering conditions.
BEGIN-END Block:
Variables assignment.
Opens the cursor.
Fetch the result into the return variable.
Closes the cursor.
Returns the fetched value.
In this case, the variables are transformed into a common table expression (CTE). As well as the query within the cursor to which, in addition, the FETCH FIRST 1 ROW ONLY
clause is added to simulate the FETCH CURSOR
behavior.
RETURN
statement is transformed to the final select.
Queries¶
CREATE OR REPLACE FUNCTION func1 (
company_ IN VARCHAR2,
book_id_ IN DATE,
object_id_ IN VARCHAR2 ) RETURN INTEGER
IS
temp_ table1.col2%TYPE;
CURSOR get_attr IS
SELECT col2
FROM table1
WHERE col3 = company_
AND col4 = object_id_
AND col5 = book_id_;
BEGIN
OPEN get_attr;
FETCH get_attr INTO temp_;
CLOSE get_attr;
RETURN temp_;
END func1;
CREATE OR REPLACE FUNCTION func1 (company_ VARCHAR, book_id_ TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/, object_id_ VARCHAR)
RETURNS INTEGER
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte1 AS
(
SELECT
(
SELECT col2
FROM table1
WHERE col3 = company_
AND col4 = object_id_
AND col5 = book_id_
FETCH FIRST 1 ROW ONLY) AS temp_
)
SELECT
temp_
FROM
declaration_variables_cte1
$$;
FUNC1() |
-----------------+
2004-05-03. |
CREATE FUNCTION func2 (
fa_period_ IN NUMBER,
to_date_ IN DATE DEFAULT NULL,
from_date_ IN DATE DEFAULT NULL ) RETURN NUMBER
IS
value_ NUMBER;
cond_date_to_ DATE;
cond_date_from_ DATE;
CURSOR get_acq_value IS
SELECT NVL(SUM(col1),0)
FROM table1
WHERE col3 IN (DECODE(fa_period_, 1, 'val1_1', 'val2_1'))
AND col5 <= cond_date_to_
AND col5 >= cond_date_from_;
BEGIN
value_ := 0;
cond_date_to_ := Get_Cond_Date( to_date_, 'MAX' );
cond_date_from_ := Get_Cond_Date( from_date_, 'MIN' );
OPEN get_acq_value;
FETCH get_acq_value INTO value_;
CLOSE get_acq_value;
RETURN (NVL(value_,0));
END func2;
CREATE OR REPLACE FUNCTION func2 (fa_period_ NUMBER(38, 18),
to_date_ TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/ DEFAULT NULL,
from_date_ TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/ DEFAULT NULL )
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte1 AS
(
SELECT
0 AS
value_,
Get_Cond_Date( to_date_, 'MAX' ) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'Get_Cond_Date' NODE ***/!!! AS
cond_date_to_,
Get_Cond_Date( from_date_, 'MIN' ) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'Get_Cond_Date' NODE ***/!!! AS
cond_date_from_
),
declaration_variables_cte2 AS
(
SELECT
(
SELECT NVL(SUM(col1),0)
FROM table1
WHERE col3 IN (DECODE(fa_period_, 1, 'val1_1', 'val2_1'))
AND col5 <= cond_date_to_
AND col5 >= cond_date_from_
FETCH FIRST 1 ROW ONLY) AS value_,
cond_date_to_,
cond_date_from_
FROM
declaration_variables_cte1
)
SELECT
(NVL(value_,0))
FROM
declaration_variables_cte2
$$;
FUNC1() |
-----------------+
2004-05-03. |
Known Issues¶
No issues were found.
Related EWIS¶
SSC-FDM-OR0042: Date Type Transformed To Timestamp Has A Different Behavior.
SSC-EWI-0073: Pending Functional Equivalence Review.
Cursor with IF statement¶
Note
Some parts in the output code are omitted for clarity reasons.
This pattern defines a function that conditionally uses a cursor to fetch and return a value based on an IF
statement.
Components:
Function Declaration:
CREATE FUNCTION functionName(parameters) RETURN returnType
Declares the function with input parameters and the return type.
Cursor Declaration:
CURSOR cursorName IS SELECT singleColumn FROM ... WHERE ... [AND col1 = localVar1];
Defines a cursor to select a single column from a table with optional filtering conditions.
Variable Declaration:
Declares variables, including the return variable.
BEGIN-END Block with IF Statement:
Variables assignment.
Check if a condition is true.
If true, opens the cursor, fetches the result into the return variable, closes the cursor, and returns the fetched value. (The cursor can also be opened in the
ELSE
block and must meet the same conditions)The
ELSE
Block is optional, if it exists, it should only contain a single statement that can be an assignment or aRETURN
statement.
The variables are transformed into a common table expression (CTE). As well as the query within the cursor to which, in addition, the FETCH FIRST 1 ROW ONLY
clause is added to simulate the FETCH CURSOR
behavior.
IF/ELSE
statement can be handled using the CASE EXPRESSION
inside the select allowing conditionals inside the queries. RETURN
statement is transformed to the final select..
Queries¶
CREATE OR REPLACE FUNCTION func1 (
company_ IN NUMBER) RETURN NUMBER
IS
CURSOR getmaxperiod IS
SELECT max(col2)
FROM table1;
max_period_ NUMBER := 12;
BEGIN
IF 1 = 1 THEN
OPEN getmaxperiod;
FETCH getmaxperiod INTO max_period_ ;
CLOSE getmaxperiod;
RETURN max_period_;
ELSE
RETURN NULL;
END IF;
END func1;
CREATE OR REPLACE FUNCTION func1 (company_ NUMBER(38, 18))
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte0 AS
(
SELECT
12 AS
max_period_
),
declaration_variables_cte1 AS
(
SELECT
CASE
WHEN 1 = 1
THEN (
SELECT max(col2)
FROM table1
FETCH FIRST 1 ROW ONLY)
ELSE NULL
END AS max_period_
FROM
declaration_variables_cte0
)
SELECT
max_period_
FROM
declaration_variables_cte1
$$;
FUNC2(0) |
--------------+
NULL |
FUNC2(1) |
--------------+
33 |
CREATE OR REPLACE FUNCTION func2(
company_ IN NUMBER) RETURN NUMBER
IS
CURSOR getmaxperiod IS
SELECT max(col2)
FROM table1;
max_period_ NUMBER := 1;
BEGIN
max_period_:= 2;
IF company_ = 1 THEN
RETURN max_period_ * 2;
ELSE
OPEN getmaxperiod;
FETCH getmaxperiod INTO max_period_ ;
CLOSE getmaxperiod;
RETURN max_period_;
END IF;
END func2;
CREATE OR REPLACE FUNCTION func2 (company_ NUMBER(38, 18))
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte0 AS
(
SELECT
1 AS
max_period_
),
declaration_variables_cte1 AS
(
SELECT
2 AS
max_period_
FROM
declaration_variables_cte0
),
declaration_variables_cte2 AS
(
SELECT
CASE
WHEN company_ = 1
THEN max_period_ * 2
ELSE (
SELECT max(col2)
FROM table1
FETCH FIRST 1 ROW ONLY)
END AS max_period_
FROM
declaration_variables_cte1
)
SELECT
max_period_
FROM
declaration_variables_cte2
$$;
FUNC2(0) |
--------------+
33 |
FUNC2(1) |
--------------+
2 |
CREATE OR REPLACE FUNCTION func3 (
company_ IN NUMBER) RETURN NUMBER
IS
CURSOR getmaxperiod IS
SELECT max(col2)
FROM table1;
max_period_ NUMBER := 0;
BEGIN
IF company_ = 1 THEN
OPEN getmaxperiod;
FETCH getmaxperiod INTO max_period_ ;
CLOSE getmaxperiod;
END IF;
RETURN max_period_;
END func10;
CREATE OR REPLACE FUNCTION func3 (company_ NUMBER(38, 18))
RETURNS NUMBER(38, 18)
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte0 AS
(
SELECT
0 AS
max_period_
),
declaration_variables_cte1 AS
(
SELECT
CASE
WHEN company_ = 1
THEN (
SELECT max(col2)
FROM table1
FETCH FIRST 1 ROW ONLY)
ELSE max_period_
END AS max_period_
FROM
declaration_variables_cte0
)
SELECT
max_period_
FROM
declaration_variables_cte1
$$;
FUNC2(0) |
--------------+
0 |
FUNC2(1) |
--------------+
33 |
Known Issues¶
No issues were found.
Related EWIS¶
No EWIs related.
Multiples IFs statement¶
This pattern defines a function that uses conditional statements over local variables.
Components:
Function Declaration:
CREATE FUNCTION functionName(parameters) RETURN returnType
Declares the function with input parameters and the return type.
Variable Declaration:
Declares variables, including the return variable.
BEGIN-END Block with IF Statement:
Check if a condition is true.
Each case is used to assign a value over the same variable.
Conversion:¶
DECLARE SECTION
: variables with default an expression are moved to a common table expression.
IF/ELSE
statement can be handled using the CASE EXPRESSION
inside the select allowing conditionals inside the queries.
RETURN
statement is transformed to the final select.
CREATE OR REPLACE FUNCTION Case1 (
in_date_ IN DATE,
min_max_ IN VARCHAR2 )
RETURN DATE
IS
cond_date_ DATE := CURRENT_DATE;
BEGIN
IF ( in_date_ IS NULL ) THEN
IF ( min_max_ = 'MIN' ) THEN
cond_date_ := FOO1();
ELSE
cond_date_ := FOO2();
END IF;
ELSE
cond_date_ := TRUNC(in_date_);
END IF;
RETURN cond_date_;
END Case1;
CREATE OR REPLACE FUNCTION Case1 (in_date_ TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/, min_max_ VARCHAR)
RETURNS TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte0 AS
(
SELECT
CURRENT_DATE AS
cond_date_
),
declaration_variables_cte1 AS
(
SELECT
CASE
WHEN ( in_date_ IS NULL )
THEN CASE
WHEN ( min_max_ = 'MIN' )
THEN FOO1() !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO1' NODE ***/!!!
ELSE FOO2() !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO2' NODE ***/!!!
END
ELSE TRUNC(in_date_, 'DD')
END AS cond_date_
FROM
declaration_variables_cte0
)
SELECT
cond_date_
FROM
declaration_variables_cte1
$$;
CREATE OR REPLACE FUNCTION Case2 (
year_ IN NUMBER,
id IN NUMBER)
RETURN VARCHAR2
IS
base_value_ NUMBER;
fully_depritiated_ VARCHAR2(5);
residual_value_ NUMBER;
acc_depr_prev_ NUMBER;
acc_depr_ NUMBER;
BEGIN
base_value_ := FOO1(year_, id);
acc_depr_ := FOO2(year_, id);
acc_depr_prev_ := FOO3(year_, id);
residual_value_ := NVL(base_value_,0) -(acc_depr_ + acc_depr_prev_);
IF (residual_value_=0 AND base_value_!=0) THEN
fully_depritiated_ := 'TRUE';
ELSE
fully_depritiated_ := 'FALSE';
END IF;
RETURN fully_depritiated_;
END Case2;
CREATE OR REPLACE FUNCTION Case2 (year_ NUMBER(38, 18), id NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte1 AS
(
SELECT
FOO1(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO1' NODE ***/!!! AS
base_value_,
FOO2(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO2' NODE ***/!!! AS
acc_depr_,
FOO3(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO3' NODE ***/!!! AS
acc_depr_prev_,
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '-' MAY NOT BEHAVE CORRECTLY BETWEEN ExactNumeric AND unknown ***/!!!
NVL(base_value_,0) -(acc_depr_ + acc_depr_prev_) AS
residual_value_,
CASE
WHEN (residual_value_=0 AND base_value_!=0)
THEN 'TRUE'
ELSE 'FALSE'
END AS fully_depritiated_
)
SELECT
fully_depritiated_
FROM
declaration_variables_cte1
$$;
CREATE OR REPLACE FUNCTION Case2_1 (
year_ IN NUMBER,
id IN NUMBER)
RETURN VARCHAR2
IS
base_value_ NUMBER;
fully_depritiated_ VARCHAR2(5);
residual_value_ NUMBER;
acc_depr_prev_ NUMBER;
acc_depr_ NUMBER;
BEGIN
base_value_ := FOO1(year_, id);
acc_depr_ := FOO2(year_, id);
acc_depr_prev_ := FOO3(year_, id);
residual_value_ := NVL(base_value_,0) -(acc_depr_ + acc_depr_prev_);
IF (residual_value_=0 AND base_value_!=0) THEN
fully_depritiated_ := 'TRUE';
ELSE
fully_depritiated_ := 'FALSE';
END IF;
fully_depritiated := fully_depritiated || ' CONCAT FOR TESTING';
fully_depritiated := fully_depritiated || ' CONCAT FOR TESTING2';
RETURN fully_depritiated_;
END Case2;
CREATE OR REPLACE FUNCTION Case2_1 (year_ NUMBER(38, 18), id NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte1 AS
(
SELECT
FOO1(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO1' NODE ***/!!! AS
base_value_,
FOO2(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO2' NODE ***/!!! AS
acc_depr_,
FOO3(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO3' NODE ***/!!! AS
acc_depr_prev_,
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '-' MAY NOT BEHAVE CORRECTLY BETWEEN ExactNumeric AND unknown ***/!!!
NVL(base_value_,0) -(acc_depr_ + acc_depr_prev_) AS
residual_value_,
CASE
WHEN (residual_value_=0 AND base_value_!=0)
THEN 'TRUE'
ELSE 'FALSE'
END AS fully_depritiated_,
NVL(fully_depritiated :: STRING, '') || ' CONCAT FOR TESTING' AS
fully_depritiated
),
declaration_variables_cte2 AS
(
SELECT
NVL(fully_depritiated :: STRING, '') || ' CONCAT FOR TESTING2' AS
fully_depritiated,
base_value_,
acc_depr_,
acc_depr_prev_,
residual_value_
FROM
declaration_variables_cte1
)
SELECT
fully_depritiated_
FROM
declaration_variables_cte2
$$;
CREATE OR REPLACE FUNCTION Case2_1 (
year_ IN NUMBER,
id IN NUMBER)
RETURN VARCHAR2
IS
base_value_ NUMBER;
fully_depritiated_ VARCHAR2(5);
residual_value_ NUMBER;
acc_depr_prev_ NUMBER;
acc_depr_ NUMBER;
BEGIN
base_value_ := FOO1(year_, id);
acc_depr_ := FOO2(year_, id);
acc_depr_prev_ := FOO3(year_, id);
residual_value_ := NVL(base_value_,0) -(acc_depr_ + acc_depr_prev_);
IF (residual_value_=0 AND base_value_!=0) THEN
fully_depritiated_ := 'TRUE';
ELSE
fully_depritiated_ := 'FALSE';
END IF;
fully_depritiated := fully_depritiated || ' CONCAT FOR TESTING';
fully_depritiated := fully_depritiated || ' CONCAT FOR TESTING2';
RETURN fully_depritiated_;
END Case2;
CREATE OR REPLACE FUNCTION Case2_1 (year_ NUMBER(38, 18), id NUMBER(38, 18))
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "oracle", "convertedOn": "09/06/2024" }}'
AS
$$
WITH declaration_variables_cte1 AS
(
SELECT
FOO1(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO1' NODE ***/!!! AS
base_value_,
FOO2(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO2' NODE ***/!!! AS
acc_depr_,
FOO3(year_, id) !!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'FOO3' NODE ***/!!! AS
acc_depr_prev_,
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '-' MAY NOT BEHAVE CORRECTLY BETWEEN ExactNumeric AND unknown ***/!!!
NVL(base_value_,0) -(acc_depr_ + acc_depr_prev_) AS
residual_value_,
CASE
WHEN (residual_value_=0 AND base_value_!=0)
THEN 'TRUE'
ELSE 'FALSE'
END AS fully_depritiated_,
NVL(fully_depritiated :: STRING, '') || ' CONCAT FOR TESTING' AS
fully_depritiated
),
declaration_variables_cte2 AS
(
SELECT
NVL(fully_depritiated :: STRING, '') || ' CONCAT FOR TESTING2' AS
fully_depritiated,
base_value_,
acc_depr_,
acc_depr_prev_,
residual_value_
FROM
declaration_variables_cte1
)
SELECT
fully_depritiated_
FROM
declaration_variables_cte2
$$;
Known Issues¶
No issues were found.
Related EWIS¶
SSC-FDM-OR0042: Date Type Transformed To Timestamp Has A Different Behavior.
SSC-EWI-0073: Pending Functional Equivalence Review.
SSC-EWI-OR0036: Types resolution issues, the arithmetic operation may not behave correctly between string and date.
DML STATEMENTS¶
Description ¶
DML statement extensions differ from normal DML statements because they can use PL/SQL elements like collections and records. So far some of these elements are not supported by snowflake scripting. If one statement is not supported, an EWI will be added during the translation. Other DML statements will be translated as if they were not inside a procedure.
The following are considered DML statements:
There is a section describing how to simulate RECORDS and COLLECTIONS behavior for SELECT and INSERT statements:
INSERT Statement Extension¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The PL/SQL extension to the SQL INSERT
statement lets you specify a record name in the values_clause
of the single_table_insert
instead of specifying a column list in the insert_into_clause.
(Oracle PL/SQL Language Reference INSERT Statement Extension)
Snowflake INSERT INTO differs from Snowflake Scripting in variable constraints; needing to have the names preceded by a colon ‘:’ in order to bind the variables’ value.
Recommendations¶
Note
This code was executed to a better understanding of the examples:
CREATE TABLE numbers_table(num integer, word varchar2(20));
CREATE OR REPLACE TABLE PUBLIC.numbers_table (num integer,
word VARCHAR(20));
INSERT Statement Extension simple case¶
Oracle¶
CREATE OR REPLACE PROCEDURE proc_insert_statement
AS
number_variable integer := 10;
word_variable varchar2(20) := 'ten';
BEGIN
INSERT INTO numbers_table VALUES(number_variable, word_variable);
INSERT INTO numbers_table VALUES(11, 'eleven');
END;
CALL proc_insert_statement();
SELECT * FROM numbers_table ;
|NUM|WORD |
|---|------|
|10 |ten |
|11 |eleven|
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE proc_insert_statement ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
number_variable integer := 10;
word_variable VARCHAR(20) := 'ten';
BEGIN
INSERT INTO numbers_table
VALUES(:number_variable, :word_variable);
INSERT INTO numbers_table
VALUES(11, 'eleven');
END;
$$;
CALL proc_insert_statement();
SELECT * FROM
numbers_table;
|NUM|WORD |
|---|------|
|10 |ten |
|11 |eleven|
Known Issues¶
1. Records are not supported by Snowflake Scripting¶
Since records are not supported by snowflake scripting, instead of using the VALUES record
clause, it is necessary to change it into a SELECT clause and split the columns of the record. For more information please see the Record Type Definition Section.
Related EWIs¶
No related EWIs.
MERGE Statement¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The MERGE
statement is used to select rows from one or more sources for update or insertion into a table or view. It is possible to specify conditions to determine whether to update or insert into the target table or view. This statement is a convenient way to combine multiple operations. It lets to avoid multiple INSERT
, UPDATE
, and DELETE
DML statements. MERGE
is a deterministic statement. It is not possible to update the same row of the target table multiple times in the same MERGE
statement. (Oracle PL/SQL Language Reference MERGE Statement))
MERGE [ hint ]
INTO [ schema. ] { table | view } [ t_alias ]
USING { [ schema. ] { table | view }
| ( subquery )
} [ t_alias ]
ON ( condition )
[ merge_update_clause ]
[ merge_insert_clause ]
[ error_logging_clause ] ;
merge_update_clause := WHEN MATCHED THEN
UPDATE SET column = { expr | DEFAULT }
[, column = { expr | DEFAULT } ]...
[ where_clause ]
[ DELETE where_clause ]
merge_insert_clause := WHEN NOT MATCHED THEN
INSERT [ (column [, column ]...) ]
VALUES ({ expr | DEFAULT }
[, { expr | DEFAULT } ]...
)
[ where_clause ]
error_logging_clause := LOG ERRORS
[ INTO [schema.] table ]
[ (simple_expression) ]
[ REJECT LIMIT { integer | UNLIMITED } ]
where_clause := WHERE condition
MERGE INTO <target_table> USING <source> ON <join_expr>
{ matchedClause | notMatchedClause } [ ... ]
matchedClause ::= WHEN MATCHED [ AND <case_predicate> ]
THEN { UPDATE SET <col_name> = <expr> [ , <col_name2> = <expr2> ... ] | DELETE } [ ... ]
notMatchedClause ::= WHEN NOT MATCHED [ AND <case_predicate> ]
THEN INSERT [ ( <col_name> [ , ... ] ) ] VALUES ( <expr> [ , ... ] )
Sample Source Patterns¶
Sample auxiliary data¶
Note
This code was executed for a better understanding of the examples:
CREATE TABLE people_source (
person_id INTEGER NOT NULL PRIMARY KEY,
first_name VARCHAR2(20) NOT NULL,
last_name VARCHAR2(20) NOT NULL,
title VARCHAR2(10) NOT NULL
);
CREATE TABLE people_target (
person_id INTEGER NOT NULL PRIMARY KEY,
first_name VARCHAR2(20) NOT NULL,
last_name VARCHAR2(20) NOT NULL,
title VARCHAR2(10) NOT NULL
);
CREATE TABLE bonuses (
employee_id NUMBER,
bonus NUMBER DEFAULT 100
);
INSERT INTO people_target
VALUES (1, 'John', 'Smith', 'Mr');
INSERT INTO people_target
VALUES (2, 'alice', 'jones', 'Mrs');
INSERT INTO people_source
VALUES (2, 'Alice', 'Jones', 'Mrs.');
INSERT INTO people_source
VALUES (3, 'Jane', 'Doe', 'Miss');
INSERT INTO people_source
VALUES (4, 'Dave', 'Brown', 'Mr');
INSERT INTO
bonuses(employee_id) (
SELECT
e.employee_id
FROM
hr.employees e,
oe.orders o
WHERE
e.employee_id = o.sales_rep_id
GROUP BY
e.employee_id
);
CREATE OR REPLACE TABLE people_source (
person_id INTEGER NOT NULL PRIMARY KEY,
first_name VARCHAR(20) NOT NULL,
last_name VARCHAR(20) NOT NULL,
title VARCHAR(10) NOT NULL
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE TABLE people_target (
person_id INTEGER NOT NULL PRIMARY KEY,
first_name VARCHAR(20) NOT NULL,
last_name VARCHAR(20) NOT NULL,
title VARCHAR(10) NOT NULL
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE TABLE bonuses (
employee_id NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
bonus NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/ DEFAULT 100
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO people_target
VALUES (1, 'John', 'Smith', 'Mr');
INSERT INTO people_target
VALUES (2, 'alice', 'jones', 'Mrs');
INSERT INTO people_source
VALUES (2, 'Alice', 'Jones', 'Mrs.');
INSERT INTO people_source
VALUES (3, 'Jane', 'Doe', 'Miss');
INSERT INTO people_source
VALUES (4, 'Dave', 'Brown', 'Mr');
INSERT INTO bonuses(employee_id) (
SELECT
e.employee_id
FROM
hr.employees e,
oe.orders o
WHERE
e.employee_id = o.sales_rep_id
GROUP BY
e.employee_id
);
MERGE Statement simple case¶
Oracle¶
MERGE INTO people_target pt USING people_source ps ON (pt.person_id = ps.person_id)
WHEN MATCHED THEN
UPDATE
SET
pt.first_name = ps.first_name,
pt.last_name = ps.last_name,
pt.title = ps.title
WHEN NOT MATCHED THEN
INSERT
(
pt.person_id,
pt.first_name,
pt.last_name,
pt.title
)
VALUES
(
ps.person_id,
ps.first_name,
ps.last_name,
ps.title
);
SELECT * FROM people_target;
PERSON_ID|FIRST_NAME|LAST_NAME|TITLE|
---------+----------+---------+-----+
1|John |Smith |Mr |
2|Alice |Jones |Mrs. |
3|Jane |Doe |Miss |
4|Dave |Brown |Mr |
Snowflake¶
MERGE INTO people_target pt USING people_source ps ON (pt.person_id = ps.person_id)
WHEN MATCHED THEN
UPDATE
SET
pt.first_name = ps.first_name,
pt.last_name = ps.last_name,
pt.title = ps.title
WHEN NOT MATCHED THEN
INSERT
(
pt.person_id,
pt.first_name,
pt.last_name,
pt.title
)
VALUES
(
ps.person_id,
ps.first_name,
ps.last_name,
ps.title
);
SELECT * FROM
people_target;
PERSON_ID|FIRST_NAME|LAST_NAME|TITLE|
---------+----------+---------+-----+
1|John |Smith |Mr |
2|Alice |Jones |Mrs. |
3|Jane |Doe |Miss |
4|Dave |Brown |Mr |
MERGE Statement with DELETE and where clause¶
In order to find an equivalence for the DELETE statement and the where clause, it is necessary to reorder and implement some changes in the Snowflake merge statement.
Changed required:¶
Replace the Oracle’s DELETE where_clause with a new Snowflake’s matchedClause with the AND predicate statement
Replace the where_clause from the Oracle’s merge_insert_clause with an AND predicate statement in the Snowflake’s notMatchedClause
Oracle¶
MERGE INTO bonuses D USING (
SELECT
employee_id,
salary,
department_id
FROM
hr.employees
WHERE
department_id = 80
) S ON (D.employee_id = S.employee_id)
WHEN MATCHED THEN
UPDATE
SET
D.bonus = D.bonus + S.salary *.01 DELETE
WHERE
(S.salary > 8000)
WHEN NOT MATCHED THEN
INSERT
(D.employee_id, D.bonus)
VALUES
(S.employee_id, S.salary *.01)
WHERE
(S.salary <= 8000);
SELECT * FROM bonuses ORDER BY employee_id;
EMPLOYEE_ID|BONUS|
-----------+-----+
153| 180|
154| 175|
155| 170|
159| 180|
160| 175|
161| 170|
164| 72|
165| 68|
166| 64|
167| 62|
171| 74|
172| 73|
173| 61|
179| 62|
Snowflake¶
--** SSC-FDM-OR0018 - SNOWFLAKE MERGE STATEMENT MAY HAVE SOME FUNCTIONAL DIFFERENCES COMPARED TO ORACLE **
MERGE INTO bonuses D USING (
SELECT
employee_id,
salary,
department_id
FROM
hr.employees
WHERE
department_id = 80) S ON (D.employee_id = S.employee_id)
WHEN MATCHED AND
(S.salary > 8000) THEN
DELETE
WHEN MATCHED THEN
UPDATE SET
D.bonus = D.bonus + S.salary *.01
WHEN NOT MATCHED AND
(S.salary <= 8000) THEN
INSERT
(D.employee_id, D.bonus)
VALUES
(S.employee_id, S.salary *.01);
SELECT * FROM
bonuses
ORDER BY employee_id;
EMPLOYEE_ID|BONUS|
-----------+-----+
153| 180|
154| 175|
155| 170|
159| 180|
160| 175|
161| 170|
164| 72|
165| 68|
166| 64|
167| 62|
171| 74|
172| 73|
173| 61|
179| 62|
Warning
In some cases the changes applied may do not work as expected, like the next example:
Oracle¶
MERGE INTO people_target pt USING people_source ps ON (pt.person_id = ps.person_id)
WHEN MATCHED THEN
UPDATE
SET
pt.first_name = ps.first_name,
pt.last_name = ps.last_name,
pt.title = ps.title DELETE
where
pt.title = 'Mrs.'
WHEN NOT MATCHED THEN
INSERT
(
pt.person_id,
pt.first_name,
pt.last_name,
pt.title
)
VALUES
(
ps.person_id,
ps.first_name,
ps.last_name,
ps.title
)
WHERE
ps.title = 'Mr';
SELECT * FROM people_target;
PERSON_ID|FIRST_NAME|LAST_NAME|TITLE|
---------+----------+---------+-----+
1|John |Smith |Mr |
4|Dave |Brown |Mr |
Snowflake¶
--** SSC-FDM-OR0018 - SNOWFLAKE MERGE STATEMENT MAY HAVE SOME FUNCTIONAL DIFFERENCES COMPARED TO ORACLE **
MERGE INTO people_target pt USING people_source ps ON (pt.person_id = ps.person_id)
WHEN MATCHED AND
pt.title = 'Mrs.' THEN
DELETE
WHEN MATCHED THEN
UPDATE SET
pt.first_name = ps.first_name,
pt.last_name = ps.last_name,
pt.title = ps.title
WHEN NOT MATCHED AND
ps.title = 'Mr' THEN
INSERT
(
pt.person_id,
pt.first_name,
pt.last_name,
pt.title
)
VALUES
(
ps.person_id,
ps.first_name,
ps.last_name,
ps.title
);
SELECT * FROM
people_target;
PERSON_ID|FIRST_NAME|LAST_NAME|TITLE|
---------+----------+---------+-----+
1|John |Smith |Mr |
2|Alice |Jones |Mrs. |
4|Dave |Brown |Mr |
Known Issues¶
1. Oracle’s error_logging_clause is not supported¶
There is no equivalent for the error logging clause in Snowflake Scripting.
2. Changed applied do not work as expected¶
Sometimes, the changes applied in order to achieve the functional equivalence between Oracle’s merge statement and Snowflake’s do not work as expected.
Related EWIs¶
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-OR0018: Merge statement may not work as expected
SELECT INTO Statement¶
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The SELECT
INTO
statement retrieves values from one or more database tables (as the SQL SELECT
statement does) and stores them in variables (which the SQL SELECT
statement does not do). (Oracle PL/SQL Language Reference SELECT INTO Statement)
SELECT [ { DISTINCT | UNIQUE } | ALL ] select_list
{ into_clause | bulk_collect_into_clause } FROM rest-of-statement ;
INTO { variable [, variable ]... | record )
BULK COLLECT INTO { collection | :host_array }
[, { collection | :host_array } ]...
SELECT [ { ALL | DISTINCT } ]
{
[{<object_name>|<alias>}.]*
| [{<object_name>|<alias>}.]<col_name>
| [{<object_name>|<alias>}.]$<col_position>
| <expr>
[ [ AS ] <col_alias> ]
}
[ , ... ]
INTO :<variable> [, :<variable> ... ]
[...]
Sample Source Patterns¶
Sample auxiliary data¶
Note
This code was executed to a better understanding of the examples:
CREATE TABLE numbers_table(num integer, word varchar2(20));
INSERT INTO numbers_table VALUES (1, 'one');
CREATE TABLE aux_numbers_table(aux_num integer, aux_word varchar2(20));
CREATE OR REPLACE TABLE numbers_table (num integer,
word VARCHAR(20))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO numbers_table
VALUES (1, 'one');
CREATE OR REPLACE TABLE aux_numbers_table (aux_num integer,
aux_word VARCHAR(20))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
SELECT INTO Statement simple case¶
Oracle¶
CREATE OR REPLACE PROCEDURE proc_select_into_variables
AS
number_variable integer;
word_variable varchar2(20);
BEGIN
SELECT * INTO number_variable, word_variable FROM numbers_table;
INSERT INTO aux_numbers_table VALUES(number_variable, word_variable);
END;
CALL proc_select_into_variables();
SELECT * FROM aux_numbers_table;
|AUX_NUM|AUX_WORD|
|-------|--------|
|1 |one |
Snowflake Scripting¶
CREATE OR REPLACE PROCEDURE proc_select_into_variables ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
number_variable integer;
word_variable VARCHAR(20);
BEGIN
SELECT * INTO
:number_variable,
:word_variable
FROM
numbers_table;
INSERT INTO aux_numbers_table
VALUES(:number_variable, :word_variable);
END;
$$;
CALL proc_select_into_variables();
SELECT * FROM
aux_numbers_table;
|AUX_NUM|AUX_WORD|
|-------|--------|
|1 |one |
Known Issues¶
1. BULK COLLECT INTO is not supported¶
Snowflake Scripting does not support the BULK COLLECT INTO clause. However, it is possible to use ARRAY_AGG to construct a new variable. For more information please see the Collection Bulk Operations Section.
2. Collections and records are not supported¶
Snowflake Scripting does not support the use of collections nor records. It is possible to migrate them using Semi-structured data types as explained in this section.
Related EWIs¶
No related EWIs.
Work around to simulate the use of Records¶
Warning
This page is deprecated but was left for compatibility purposes. If you want to see the updated section, please refer to Collections And Records
Description¶
This section describes how to simulate the behavior of Oracle records in SELECT and INSERT Statements, using RESULTSET and CURSORS of Snowflake Scripting.
Snowflake Scripting RESULTSET and CURSOR¶
<resultset_name> RESULTSET [ DEFAULT ( <query> ) ] ;
LET <resultset_name> RESULTSET [ { DEFAULT | := } ( <query> ) ] ;
LET <resultset_name> RESULTSET [ { DEFAULT | := } ( <query> ) ] ;
Recommendations¶
Note
For the following examples, this code was executed to better understanding of the examples:
CREATE TABLE numbers_table(num integer, word varchar2(20));
INSERT INTO numbers_table VALUES (1, 'one');
CREATE TABLE aux_numbers_table(aux_num integer, aux_word varchar2(20));
CREATE OR REPLACE TABLE numbers_table (num integer,
word VARCHAR(20))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO numbers_table
VALUES (1, 'one');
CREATE OR REPLACE TABLE aux_numbers_table (aux_num integer,
aux_word VARCHAR(20))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
Using RESULTSET and Cursors instead of Records¶
Oracle¶
CREATE OR REPLACE PROCEDURE proc_insert_select_resultset
AS
TYPE number_record_definition IS RECORD(
rec_num numbers_table.num%type,
rec_word numbers_table.word%type
);
number_record number_record_definition;
BEGIN
SELECT * INTO number_record FROM numbers_table;
INSERT INTO aux_numbers_table VALUES number_record;
END;
CALL proc_insert_select_resultset();
SELECT * FROM aux_numbers_table;
|AUX_NUM|AUX_WORD|
|-------|--------|
|1 |one |
Snowflake¶
CREATE OR REPLACE PROCEDURE proc_insert_select_resultset ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
!!!RESOLVE EWI!!! /*** SSC-EWI-0056 - CUSTOM TYPES ARE NOT SUPPORTED IN SNOWFLAKE BUT REFERENCES TO THIS CUSTOM TYPE WERE CHANGED TO OBJECT ***/!!!
TYPE number_record_definition IS RECORD(
rec_num numbers_table.num%type,
rec_word numbers_table.word%type
);
number_record OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - number_record_definition DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
BEGIN
SELECT
OBJECT_CONSTRUCT( *) INTO
:number_record
FROM
numbers_table;
INSERT INTO aux_numbers_table
SELECT
:number_record:REC_NUM,
:number_record:REC_WORD;
END;
$$;
CALL proc_insert_select_resultset();
SELECT * FROM
aux_numbers_table;
CREATE OR REPLACE PROCEDURE PUBLIC.proc_select_into()
RETURNS INTEGER
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
AS
$$
DECLARE
NUMBER_VARIABLE INTEGER;
WORD_VARIABLE VARCHAR;
NUMBER_RECORD RESULTSET;
BEGIN
LET c2 CURSOR FOR NUMBER_RECORD;
FOR row_variable IN c2 DO
let var1 integer := row_variable.num;
let var2 varchar := row_variable.word;
INSERT INTO PUBLIC.aux_numbers_table VALUES(:var1, :var2);
END FOR;
end;
$$;
|AUX_NUM|AUX_WORD|
|-------|--------|
|1 |one |
Known Issues¶
1. Limitation in the use of RESULTSET¶
RESULTSET is very limited in its use. If table(result_scan(last_query_id()))
statement, should be used just after the RESULTSET’s query is executed. For further information check this link.
Related EWIs¶
SSC-EWI-0036: Data type converted to another data type.
SSC-EWI-0056: Create Type Not Supported.
PACKAGES¶
Description¶
Use the CREATE
PACKAGE
statement to create the specification for a stored package, which is an encapsulated collection of related procedures, functions, and other program objects stored together in the database. The package specification declares these objects. The package body, specified subsequently, defines these objects.(Oracle PL/SQL Language Reference CREATE PACKAGE Statement)
Snowflake does not have an equivalent for Oracle packages, so in order to maintain the structure, the packages are transformed into a schema, and all its elements are defined inside it. Also, the package and its elements are renamed to preserve the original schema name. For more information about package renaming, you can check the Package Translation Options section.
BODY¶
Description¶
The header of the PACKAGE BODY is removed and each procedure or function definition is transformed into a standalone function or procedure.
CREATE [ OR REPLACE ]
[ EDITIONABLE | NONEDITIONABLE ]
PACKAGE BODY plsql_package_body_source
Sample Source Patterns¶
Note
The following queries were transformed with the PackagesAsSchema option disabled.
Oracle¶
CREATE OR REPLACE PACKAGE BODY SCHEMA1.PKG1 AS
PROCEDURE procedure1 AS
BEGIN
dbms_output.put_line('hello world');
END;
END package1;
Snowflake¶
CREATE OR REPLACE PROCEDURE SCHEMA1_PKG1.procedure1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF('hello world');
END;
$$;
Known Issues¶
No issues were found.
Related EWIs¶
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
Constants¶
Description¶
PACKAGE CONSTANTS can be declared either in the package declaration or in the PACKAGE BODY. When a package constant is used in a procedure, a new variable is declared with the same name and value as the constant, so the resulting code is pretty similar to the input.
constant CONSTANT datatype [NOT NULL] { := | DEFAULT } expression ;
Sample Source Patterns¶
Sample auxiliary code¶
create table table1(id number);
CREATE OR REPLACE TABLE table1 (id NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
Oracle¶
CREATE OR REPLACE PACKAGE PKG1 AS
PROCEDURE procedure1;
package_constant CONSTANT NUMBER:= 9999;
END PKG1;
CREATE OR REPLACE PACKAGE BODY PKG1 AS
PROCEDURE procedure1 AS
BEGIN
INSERT INTO TABLE1(ID) VALUES(package_constant);
END;
END PKG1;
CALL PKG1.procedure1();
SELECT * FROM TABLE1;
|ID |
|----|
|9999|
Snowflake¶
CREATE SCHEMA IF NOT EXISTS PKG1
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE PKG1.procedure1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
PACKAGE_CONSTANT NUMBER := 9999;
BEGIN
INSERT INTO TABLE1(ID) VALUES(:PACKAGE_CONSTANT);
END;
$$;
CALL PKG1.procedure1();
SELECT * FROM
TABLE1;
|ID |
|----|
|9999|
Note
Note that thePROCEDURE
definition is being removed since it is not required in Snowflake.
Known Issues¶
No issues were found.
Related EWIs¶
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
DECLARATION¶
Description¶
The declaration is converted to a schema, so each inner element is declared inside this schema. All the elements present in the package are commented except for the VARIABLES which have a proper transformation.
CREATE [ OR REPLACE ]
[ EDITIONABLE | NONEDITIONABLE ]
PACKAGE plsql_package_source
Sample Source Patterns¶
Note
The following queries were transformed with the PackagesAsSchema option disabled.
Oracle¶
CREATE OR REPLACE PACKAGE SCHEMA1.PKG1 AS
-- Function Declaration
FUNCTION function_declaration(param1 VARCHAR) RETURN INTEGER;
-- Procedure Declaration
PROCEDURE procedure_declaration(param1 VARCHAR2, param2 VARCHAR2);
END PKG1;
Snowflake¶
CREATE SCHEMA IF NOT EXISTS SCHEMA1_PKG1
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
Note
Note that both FUNCTION
and PROCEDURE
definitions are being removed since they are not required in Snowflake.
Known Issues¶
No issues were found.
Related EWIs¶
No related EWIs.
VARIABLES¶
Description¶
PACKAGE VARIABLES can be declared either in the package declaration or in the PACKAGE BODY. Due to its behavior, these variables are converted into Snowflake session variables so each usage or assignment is translated to its equivalent in Snowflake.
variable datatype [ [ NOT NULL] {:= | DEFAULT} expression ] ;
Sample Source Patterns¶
Sample auxiliary code¶
create table table1(id number);
CREATE OR REPLACE TABLE table1 (id NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
Variable declaration¶
Oracle¶
CREATE OR REPLACE PACKAGE PKG1 AS
package_variable NUMBER:= 100;
END PKG1;
Snowflake Scripting¶
CREATE SCHEMA IF NOT EXISTS PKG1
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
SET "PKG1.PACKAGE_VARIABLE" = '' || (100);
Variable Usage¶
Package variable usages are transformed into the Snowflake GETVARIABLE function which accesses the current value of a session variable. An explicit cast is added to the original variable data type in order to maintain the functional equivalence in the operations where these variables are used.
Oracle¶
CREATE OR REPLACE PACKAGE PKG1 AS
PROCEDURE procedure1;
package_variable NUMBER:= 100;
END PKG1;
CREATE OR REPLACE PACKAGE BODY PKG1 AS
PROCEDURE procedure1 AS
BEGIN
INSERT INTO TABLE1(ID) VALUES(package_variable);
END;
END PKG1;
CALL SCHEMA1.PKG1.procedure1();
SELECT * FROM TABLE1;
|ID |
|---|
|100|
Snowflake¶
CREATE SCHEMA IF NOT EXISTS PKG1
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
SET "PKG1.PACKAGE_VARIABLE" = '' || (100);
CREATE OR REPLACE PROCEDURE PKG1.procedure1 ()
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 TABLE1(ID) VALUES(GETVARIABLE('PKG1.PACKAGE_VARIABLE') :: NUMBER);
END;
$$;
CALL SCHEMA1.PKG1.procedure1();
SELECT * FROM
TABLE1;
|ID |
|---|
|100|
Note
Note that the PROCEDURE
definition in the package is removed since it is not required by Snowflake.
Variable regular assignment¶
When a package variable is assigned using the :=
operator, the assignation is replaced by a SnowConvert UDF called UPDATE_PACKAGE_VARIABLE_STATE which is an abstraction of the Snowflake SETVARIABLE function.
Oracle
CREATE OR REPLACE PACKAGE PKG1 AS
PROCEDURE procedure1;
package_variable NUMBER:= 100;
END PKG1;
CREATE OR REPLACE PACKAGE BODY PKG1 AS
PROCEDURE procedure1 AS
BEGIN
package_variable := package_variable + 100;
INSERT INTO TABLE1(ID) VALUES(package_variable);
END;
END PKG1;
CALL PKG1.procedure1();
SELECT * FROM TABLE1;
|ID |
|---|
|200|
Snowflake
CREATE SCHEMA IF NOT EXISTS PKG1
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
SET "PKG1.PACKAGE_VARIABLE" = '' || (100);
CREATE OR REPLACE PROCEDURE PKG1.procedure1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
CALL UPDATE_PACKAGE_VARIABLE_STATE_UDF('PKG1.PACKAGE_VARIABLE', TO_VARCHAR(GETVARIABLE('PKG1.PACKAGE_VARIABLE') :: NUMBER + 100));
INSERT INTO TABLE1(ID) VALUES(GETVARIABLE('PKG1.PACKAGE_VARIABLE') :: NUMBER);
END;
$$;
CALL PKG1.procedure1();
SELECT * FROM
TABLE1;
|ID |
|---|
|200|
Note
Note that the PROCEDURE
definition in the package is removed since it is not required by Snowflake.
Variable assignment as an output argument¶
When a package variable is used as an output argument a new variable is declared inside the procedure, this variable will catch the output argument value of the procedure, and then the variable will be used to update the session variable which refers to the package variable using the UPDATE_PACKAGE_VARIABLE_STATE mentioned above. For more information check de output parameters transformation.
Oracle¶
CREATE OR REPLACE PACKAGE PKG1 AS
PROCEDURE procedure1;
PROCEDURE procedure2(out_param OUT NUMBER);
package_variable NUMBER:= 100;
END PKG1;
CREATE OR REPLACE PACKAGE BODY PKG1 AS
PROCEDURE procedure1 AS
BEGIN
procedure2(package_variable);
INSERT INTO TABLE1(ID) VALUES(package_variable);
END;
PROCEDURE procedure2 (out_param OUT NUMBER) AS
BEGIN
out_param := 1000;
END;
END PKG1;
CALL PKG1.procedure1();
|ID |
|----|
|1000|
Snowflake¶
CREATE SCHEMA IF NOT EXISTS PKG1
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
SET "PKG1.PACKAGE_VARIABLE" = '' || (100);
CREATE OR REPLACE PROCEDURE PKG1.procedure1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
PKG1_PACKAGE_VARIABLE VARIANT;
call_results VARIANT;
BEGIN
call_results := (
CALL PKG1.
procedure2(:PKG1_PACKAGE_VARIABLE)
);
PKG1_PACKAGE_VARIABLE := :call_results;
CALL UPDATE_PACKAGE_VARIABLE_STATE_UDF('PKG1.PACKAGE_VARIABLE', TO_VARCHAR(:PKG1_PACKAGE_VARIABLE));
INSERT INTO TABLE1(ID) VALUES(GETVARIABLE('PKG1.PACKAGE_VARIABLE') :: NUMBER);
END;
$$;
CREATE OR REPLACE PROCEDURE PKG1.procedure2 (out_param NUMBER(38, 18))
RETURNS VARIANT
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
BEGIN
out_param := 1000;
RETURN null;
END;
$$;
CALL PKG1.procedure1();
|ID |
|----|
|1000|
Note
Note that the PROCEDURE
definition in the package is removed since it is not required by Snowflake.
Known Issues¶
No issues were found.
Related EWIs¶
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
COLLECTIONS AND RECORDS¶
Warning
This section is a work in progress, information may change in the future.
General Description¶
PL/SQL lets you define two kinds of composite data types: collection and record, where composite is a data type that stores values that have internal components.
In a collection, the internal components always have the same data type, and are called elements.
In a record, the internal components can have different data types, and are called fields. (Oracle PL/SQL Language Reference COLLECTIONS AND RECORDS)
Note
Please take into account the CREATE TYPE statement translation reference since some workarounds can overlap and may be functional in both scenarios.
Limitations¶
Snowflake doesn’t support user-defined data types, which includes PL Collections and Records, according to its online documentation Unsupported Data Types, but it supports Semi-structured Data Types, which can be used to mimic both the hierarchy-like structure of Record and the element structure of Collection User-defined types. For this reason, there are multiple types of features that have no workaround.
Following are the features for which NO workaround is proposed:
Variable size cannot exceed 16MB¶
Snowflake sets VARIANT, OBJECT, and ARRAY’s maximum size on 16MBs. This means that if a Record, a Collection, or any element of either exceeds this size it will cause a Runtime Error.
Varray capacity cannot be limited¶
Oracle’s varrays offer the capacity to limit the number of elements within them. This is not supported by Snowflake.
Proposed Workaround¶
About Record types definition¶
The proposed workaround is to use an “OBJECT” semi-structured data type to mimic Oracle’s data type.
About Collection types definition¶
There are two different workarounds that depend on the type of collection to be migrated:
Associative Arrays are proposed to be changed into an “OBJECT” semi-structured data type.
Varrays and Nested Table Arrays are proposed to be changed into an “ARRAY” semi-structured data type.
Current SnowConvert Support¶
The next table shows a summary of the current support provided by the SnowConvert tool. Please keep into account that translations may still not be final, and more work may be needed.
Sub-Feature | Current recognition status | Current translation status | Has Known Workarounds |
---|---|---|---|
Record Type Definitions | Recognized. | Not Translated. | Yes. |
Associative Array Type Definitions | Not Recognized. | Not Translated. | Yes. |
Varray Type Definitions | Recognized. | Not Translated. | Yes. |
Nested Table Array Type Definitions | Recognized. | Not Translated. | Yes. |
Known Issues¶
1. Associate Arrays are considered a Nested Table¶
As of now, SnowConvert doesn’t differentiate between an Associative Array and a Nested Table meaning they are mixed up in the same assessment counts.
Related EWIs¶
No related EWIs.
Associative Array Type Definition¶
Warning
This section is a work in progress, information may change in the future.
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
An associative array (formerly called PL/SQL table or index-by table) is a set of key-value pairs. Each key is a unique index, used to locate the associated value with the syntax variable_name(index)
.
The data type of index
can be either a string type (VARCHAR2
, VARCHAR
, STRING
, or LONG
) or PLS_INTEGER
. Indexes are stored in sort order, not creation order. For string types, sort order is determined by the initialization parameters NLS_SORT
and NLS_COMP
.
(Oracle PL/SQL Language Reference ASSOCIATIVE ARRAYS)
Warning
Not to be confused with the PL/SQL NESTED TABLE Type definition.
For the translation, the type definition is replaced by an OBJECT Semi-structured Data Type and then its usages are changed accordingly across any operations.
In order to define an Associative Array type, the syntax is as follows:
type_definition := TYPE IS TABLE OF datatype INDEX BY indexing_datatype;
indexing_datatype := { PLS_INTEGER
| BINARY_INTEGER
| string_datatype
}
To declare a variable of this type:
variable_name collection_type;
Sample Source Patterns¶
Varchar-indexed Associative Array¶
Oracle¶
CREATE OR REPLACE PROCEDURE associative_array
IS
TYPE associate_array_typ IS TABLE OF INTEGER
INDEX BY VARCHAR2(50);
associate_array associate_array_typ := associate_array_typ();
associate_index VARCHAR2(50);
BEGIN
associate_array('abc') := 1;
associate_array('bca') := 2;
associate_array('def') := 3;
DBMS_OUTPUT.PUT_LINE(associate_array('abc'));
associate_array('abc') := 4;
--THROWS 'NO DATA FOUND'
--DBMS_OUTPUT.PUT_LINE(associate_array('no exists'));
DBMS_OUTPUT.PUT_LINE(associate_array.COUNT);
associate_index := associate_array.FIRST;
WHILE associate_index IS NOT NULL
LOOP
DBMS_OUTPUT.PUT_LINE(associate_array(associate_index));
associate_index := associate_array.NEXT(associate_index);
END LOOP;
END;
CALL associative_array();
DBMS OUTPUT
-----------
1
3
4
2
3
Snowflake¶
Please note the ‘true’ parameter in the OBJECT_INSERT. This is so that the element is updated if it is already present in the array.
CREATE OR REPLACE PROCEDURE PUBLIC.associative_array ()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associate_array OBJECT := OBJECT_CONSTRUCT();
associate_index VARCHAR(50);
BEGIN
associate_array := OBJECT_INSERT(associate_array, 'abc', 1, true);
associate_array := OBJECT_INSERT(associate_array, 'bca', 2, true);
associate_array := OBJECT_INSERT(associate_array, 'def', 3, true);
CALL DBMS_OUTPUT.PUT_LINE(:associate_array['abc']);
CALL DBMS_OUTPUT.PUT_LINE(:associate_array['not found']);
associate_array := OBJECT_INSERT(:associate_array, 'abc', 4, true);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(OBJECT_KEYS(:associate_array)));
FOR i IN 1 TO ARRAY_SIZE(OBJECT_KEYS(:associate_array))
LOOP
associate_index := OBJECT_KEYS(:associate_array)[:i-1];
CALL DBMS_OUTPUT.PUT_LINE(:associate_array[:associate_index]);
END LOOP;
END;
$$;
CALL PUBLIC.associative_array();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
1
3
4
2
3
Numeric-indexed Associative Array¶
Oracle¶
CREATE OR REPLACE PROCEDURE numeric_associative_array
IS
TYPE numeric_associative_array_typ IS TABLE OF INTEGER
INDEX BY PLS_INTEGER;
associate_array numeric_associativ
e_array_typ := numeric_associative_array_typ();
associate_index PLS_INTEGER;
BEGIN
associate_array(1) := -1;
associate_array(2) := -2;
associate_array(3) := -3;
DBMS_OUTPUT.PUT_LINE(associate_array(1));
associate_array(1) := -4;
DBMS_OUTPUT.PUT_LINE(associate_array.COUNT);
associate_index := associate_array.FIRST;
WHILE associate_index IS NOT NULL
LOOP
DBMS_OUTPUT.PUT_LINE(associate_array(associate_index));
associate_index := associate_array.NEXT(associate_index);
END LOOP;
END;
CALL numeric_associative_array();
DBMS OUTPUT
-----------
-1
3
-4
-2
-3
Snowflake¶
Please note that the numeric value is converted to varchar accordingly when the operation needs it. Additionally, note the ‘true’ parameter in the OBJECT_INSERT. This is so that the element is updated if it is already present in the array.
CREATE OR REPLACE PROCEDURE PUBLIC.numeric_associative_array ()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associate_array OBJECT := OBJECT_CONSTRUCT();
associate_index NUMBER;
BEGIN
associate_array := OBJECT_INSERT(associate_array, '1', -1, true);
associate_array := OBJECT_INSERT(associate_array, '2', -2, true);
associate_array := OBJECT_INSERT(associate_array, '3', -3, true);
CALL DBMS_OUTPUT.PUT_LINE(:associate_array['1']);
associate_array := OBJECT_INSERT(:associate_array, '1', -4, true);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(OBJECT_KEYS(:associate_array)));
FOR i IN 1 TO ARRAY_SIZE(OBJECT_KEYS(:associate_array))
LOOP
associate_index := OBJECT_KEYS(:associate_array)[:i-1];
CALL DBMS_OUTPUT.PUT_LINE(:associate_array[:associate_index::VARCHAR]);
END LOOP;
END;
$$;
CALL PUBLIC.numeric_associative_array();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
-1
3
-4
-2
-3
Record-element Numeric-indexed Associative Array¶
In this case, the associative array is composed of a Record-structure, and this structure needs to be preserved. For this purpose, further operations on insertions were added.
Oracle¶
CREATE OR REPLACE PROCEDURE record_associative_array
IS
TYPE record_typ IS RECORD(col1 INTEGER);
TYPE record_associative_array_typ IS TABLE OF record_typ
INDEX BY PLS_INTEGER;
associate_array record_associati ve_array_typ := record_associative_array_typ();
associate_index PLS_INTEGER;
BEGIN
associate_array(1).col1 := -1;
associate_array(2).col1 := -2;
associate_array(3).col1 := -3;
DBMS_OUTPUT.PUT_LINE(associate_array(1).col1);
associate_array(4).col1 := -4;
DBMS_OUTPUT.PUT_LINE(associate_array.COUNT);
associate_index := associate_array.FIRST;
WHILE associate_index IS NOT NULL
LOOP
DBMS_OUTPUT.PUT_LINE(associate_array(associate_index).col1);
associate_index := associate_array.NEXT(associate_index);
END LOOP;
END;
/
CALL record_associative_array();
DBMS OUTPUT
-----------
-1
3
-4
-2
-3
Snowflake¶
In this scenario, the insertion/update assumes an automatic creation of the record within the associative array and this needs to be taken into account when creating new records.
CREATE OR REPLACE PROCEDURE PUBLIC.record_associative_array ()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associate_array OBJECT := OBJECT_CONSTRUCT();
associate_index NUMBER;
BEGIN
associate_array := OBJECT_INSERT(associate_array, '1', OBJECT_INSERT(NVL(associate_array['1'], OBJECT_CONSTRUCT()), 'col1', -1, true), true);
associate_array := OBJECT_INSERT(associate_array, '2', OBJECT_INSERT(NVL(associate_array['2'], OBJECT_CONSTRUCT()), 'col1', -2, true), true);
associate_array := OBJECT_INSERT(associate_array, '3', OBJECT_INSERT(NVL(associate_array['3'], OBJECT_CONSTRUCT()), 'col1', -3, true), true);
CALL DBMS_OUTPUT.PUT_LINE(:associate_array['1']:col1);
associate_array := OBJECT_INSERT(associate_array, '1', OBJECT_INSERT(NVL(associate_array['1'], OBJECT_CONSTRUCT()), 'col1', -4, true), true);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(OBJECT_KEYS(:associate_array)));
FOR i IN 1 TO ARRAY_SIZE(OBJECT_KEYS(:associate_array))
LOOP
associate_index := OBJECT_KEYS(:associate_array)[:i-1];
CALL DBMS_OUTPUT.PUT_LINE(:associate_array[:associate_index::VARCHAR]:col1);
END LOOP;
END;
$$;
CALL PUBLIC.record_associative_array();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
-1
3
-4
-2
-3
Known Issues¶
1. They are currently not being recognized¶
SnowConvert treats these collections as Nested Table Arrays. There is a work item to fix this.
Related EWIs¶
No related EWIs.
Collection Methods¶
Warning
This section is a work in progress, information may change in the future
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
A collection method is a PL/SQL subprogram—either a function that returns information about a collection or a procedure that operates on a collection. Collection methods make collections easier to use and your applications easier to maintain.
(Oracle PL/SQL Language Reference COLLECTION METHODS)
Some of these methods can be mapped to native Snowflake semi-structured operations. The ones that can’t or have differences will be mapped to a UDF implementation.
Current SnowConvert Support¶
The next table shows a summary of the current support provided by the SnowConvert tool. Please keep into account that translations may still not be final, and more work may be needed.
Method | Current recognition status | Current translation status | Mapped to |
---|---|---|---|
DELETE | Not Recognized. | Not Translated. | UDF |
TRIM | Not Recognized. | Not Translated. | UDF (To be defined) |
EXTEND | Not Recognized. | Not Translated. | UDF |
EXISTS | Not Recognized. | Not Translated. | ARRAY_CONTAINS |
FIRST | Not Recognized. | Not Translated. | UDF |
LAST | Not Recognized. | Not Translated. | UDF |
COUNT | Not Recognized. | Not Translated. | ARRAY_SIZE |
LIMIT | Not Recognized. | Not Translated. | Not Supported. |
PRIOR | Not Recognized. | Not Translated. | UDF (To be defined) |
NEXT | Not Recognized. | Not Translated. | UDF (To be defined) |
Sample Source Patterns¶
COUNT¶
This method returns the count of “non-undefined” (not to be confused with null) elements within a collection (nested tables can become sparse leaving these elements in between). In associative arrays, it returns the number of keys in the array.
Oracle¶
CREATE OR REPLACE PROCEDURE collection_count
IS
TYPE varray_typ IS VARRAY(5) OF INTEGER;
TYPE nt_typ IS TABLE OF INTEGER;
TYPE aa_typ IS TABLE OF INTEGER INDEX BY VARCHAR2(20);
associative_array aa_typ := aa_typ('abc'=>1, 'bca'=>1);
varray_variable varray_typ := varray_typ(1, 2, 3);
nt_variable nt_typ := nt_typ(1, 2, 3, 4);
BEGIN
DBMS_OUTPUT.PUT_LINE(associative_array.COUNT);
DBMS_OUTPUT.PUT_LINE(varray_variable.COUNT);
DBMS_OUTPUT.PUT_LINE(nt_variable.COUNT);
END;
CALL collection_count();
DBMS OUTPUT
-----------
2
3
4
Snowflake¶
The snowflake equivalent is the ARRAY_SIZE method.
CREATE OR REPLACE PROCEDURE PUBLIC.collection_count()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associative_array OBJECT := OBJECT_CONSTRUCT('abc', 1, 'bca', 1);
varray_variable ARRAY := ARRAY_CONSTRUCT(1, 2, 3);
nt_variable ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
BEGIN
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(OBJECT_KEYS(:associative_array)));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(:varray_variable));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(:nt_variable));
END;
$$;
CALL PUBLIC.collection_count();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
2
3
4
EXISTS¶
This method returns true if the given element is contained within the collection. In associative arrays, it tests if the key is contained.
Oracle¶
CREATE OR REPLACE PROCEDURE collection_exists
IS
TYPE nt_typ IS TABLE OF INTEGER;
TYPE aa_typ IS TABLE OF INTEGER INDEX BY VARCHAR2(20);
associative_array aa_typ := aa_typ('abc'=>1, 'bca'=>1);
nt_variable nt_typ := nt_typ(1, 2, 3, 4);
BEGIN
IF associative_array.EXISTS('abc')
THEN DBMS_OUTPUT.PUT_LINE('Found');
END IF;
IF NOT associative_array.EXISTS('not found')
THEN DBMS_OUTPUT.PUT_LINE('Not found');
END IF;
IF nt_variable.EXISTS(1)
THEN DBMS_OUTPUT.PUT_LINE('Found');
END IF;
IF NOT nt_variable.EXISTS(5)
THEN DBMS_OUTPUT.PUT_LINE('Not found');
END IF;
END;
/
CALL collection_exists();
DBMS OUTPUT
-----------
2
3
4
Snowflake¶
The snowflake equivalent is the ARRAY_CONTAINS method. Note that, when using Varchar elements, casting to Variant is necessary.
CREATE OR REPLACE PROCEDURE PUBLIC.collection_exists()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associative_array OBJECT := OBJECT_CONSTRUCT('abc', 1, 'bca', 1);
nt_variable ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
BEGIN
IF (ARRAY_CONTAINS('abc'::VARIANT, OBJECT_KEYS(associative_array)))
THEN CALL DBMS_OUTPUT.PUT_LINE('Found');
END IF;
IF (NOT ARRAY_CONTAINS('not found'::VARIANT, OBJECT_KEYS(associative_array)))
THEN CALL DBMS_OUTPUT.PUT_LINE('Not found');
END IF;
IF (ARRAY_CONTAINS(1, nt_variable))
THEN CALL DBMS_OUTPUT.PUT_LINE('Found');
END IF;
IF (NOT ARRAY_CONTAINS(5, nt_variable))
THEN CALL DBMS_OUTPUT.PUT_LINE('Not found');
END IF;
END;
$$;
CALL PUBLIC.collection_exists();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
2
3
4
FIRST/LAST¶
These two methods return the First/Last element of the collection, respectively. If the collection is empty it returns null. This operation is mapped to a UDF, which will be added in further revisions.
Oracle¶
CREATE OR REPLACE PROCEDURE collection_first_last
IS
TYPE nt_typ IS TABLE OF INTEGER;
TYPE aa_typ IS TABLE OF INTEGER INDEX BY VARCHAR2(20);
associative_array aa_typ := aa_typ('abc'=>1, 'bca'=>1);
nt_variable nt_typ := nt_typ();
BEGIN
DBMS_OUTPUT.PUT_LINE(associative_array.FIRST);
DBMS_OUTPUT.PUT_LINE(associative_array.LAST);
DBMS_OUTPUT.PUT_LINE(nt_variable.FIRST);
DBMS_OUTPUT.PUT_LINE(nt_variable.LAST);
nt_variable := nt_typ(1, 2, 3, 4);
DBMS_OUTPUT.PUT_LINE(nt_variable.FIRST);
DBMS_OUTPUT.PUT_LINE(nt_variable.LAST);
END;
/
CALL collection_first_last();
DBMS OUTPUT
-----------
abc
bca
--These empty spaces are due to it evaluating to null
1
4
Snowflake¶
CREATE OR REPLACE PROCEDURE PUBLIC.collection_first_last()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associative_array OBJECT := OBJECT_CONSTRUCT('abc', 1, 'bca', 1);
nt_variable ARRAY := ARRAY_CONSTRUCT();
BEGIN
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_FIRST(:associative_array));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_LAST(:associative_array));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_FIRST(:nt_variable));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_LAST(:nt_variable));
nt_variable := ARRAY_CONSTRUCT(1, 2, 3, 4);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_FIRST(:nt_variable));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_LAST(:nt_variable));
END;
$$;
CALL PUBLIC.collection_first_last();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
CREATE OR REPLACE FUNCTION ARRAY_FIRST(array_variable VARIANT)
RETURNS VARIANT
LANGUAGE SQL
AS
$$
IFF (IS_OBJECT(array_variable),
ARRAY_FIRST(OBJECT_KEYS(array_variable)),
IFF (ARRAY_SIZE(array_variable) = 0, null, array_variable[0]))
$$;
CREATE OR REPLACE FUNCTION ARRAY_LAST(array_variable VARIANT)
RETURNS VARIANT
LANGUAGE SQL
AS
$$
IFF (IS_OBJECT(array_variable),
ARRAY_LAST(OBJECT_KEYS(array_variable)),
IFF (ARRAY_SIZE(array_variable) = 0, null, array_variable[ARRAY_SIZE(array_variable)-1]))
$$;
DBMS OUTPUT
-----------
abc
bca
--These empty spaces are due to it evaluating to null
1
4
DELETE¶
This method is used to remove elements from a Collection. It has three possible variants:
.DELETE removes all elements.
.DELETE(n) removes the element whose index matches ‘n’.
.DELETE(n, m) removes in the indexes from ‘n’ through ‘m’.
Note
In Oracle, using this operation on Nested Tables causes it to have “undefined” elements within it due to them being sparse.
Warning
Please note that the second and third versions do not apply to Varrays.
Oracle¶
For the sake of simplicity, this sample only checks on the number of elements but may be modified to display the contents of each collection.
CREATE OR REPLACE PROCEDURE collection_delete
IS
TYPE varray_typ IS VARRAY(5) OF INTEGER;
TYPE nt_typ IS TABLE OF INTEGER;
TYPE aa_typ IS TABLE OF INTEGER INDEX BY VARCHAR2(20);
associative_array1 aa_typ := aa_typ('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
associative_array2 aa_typ := aa_typ('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
associative_array3 aa_typ := aa_typ('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
varray_variable1 varray_typ := varray_typ(1, 2, 3, 4);
nt_variable1 nt_typ := nt_typ(1, 2, 3, 4);
nt_variable2 nt_typ := nt_typ(1, 2, 3, 4);
nt_variable3 nt_typ := nt_typ(1, 2, 3, 4);
BEGIN
varray_variable1.DELETE;--delete everything
nt_variable1.DELETE;--delete everything
nt_variable2.DELETE(2);--delete second position
nt_variable3.DELETE(2, 3);--delete range
associative_array1.DELETE;--delete everything
associative_array2.DELETE('def');--delete second position
associative_array3.DELETE('def', 'jkl');--delete range
DBMS_OUTPUT.PUT_LINE(varray_variable1.COUNT);
DBMS_OUTPUT.PUT_LINE(nt_variable1.COUNT);
DBMS_OUTPUT.PUT_LINE(nt_variable2.COUNT);
DBMS_OUTPUT.PUT_LINE(nt_variable3.COUNT);
DBMS_OUTPUT.PUT_LINE(associative_array1.COUNT);
DBMS_OUTPUT.PUT_LINE(associative_array2.COUNT);
DBMS_OUTPUT.PUT_LINE(associative_array3.COUNT);
END;
/
CALL collection_delete();
DBMS OUTPUT
-----------
0
0
3
2
0
3
1
Snowflake¶
Snowflake does not support deletions from an existing ARRAY and for this reason, the only offered workaround is to rebuild a new ARRAY depending on the original parameters of the DELETE.
Note
Note that a UDF was added to implement the functionality for the update of the element.
This UDF will be added in later revisions.
CREATE OR REPLACE PROCEDURE PUBLIC.collection_delete()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
associative_array1 OBJECT := OBJECT_CONSTRUCT('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
associative_array2 OBJECT := OBJECT_CONSTRUCT('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
associative_array3 OBJECT := OBJECT_CONSTRUCT('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
varray_variable1 ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
nt_variable1 ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
nt_variable2 ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
nt_variable3 ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
BEGIN
varray_variable1 := ARRAY_CONSTRUCT();--delete everything
nt_variable1 := ARRAY_CONSTRUCT();--delete everything
nt_variable2 := ARRAY_DELETE_UDF(nt_variable2, 2);--delete second position
nt_variable3 := ARRAY_DELETE_UDF(nt_variable3, 2, 3);--delete range
associative_array1 := OBJECT_CONSTRUCT();--delete everything
associative_array2 := ASSOCIATIVE_ARRAY_DELETE_UDF('def');--delete second position
associative_array3 := ASSOCIATIVE_ARRAY_DELETE_UDF('def', 'jkl');--delete range
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(varray_variable1));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(nt_variable1);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(nt_variable2);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(nt_variable3);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(associative_array1));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(associative_array2));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(associative_array3));
END;
$$;
CALL PUBLIC.collection_first_last();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
0
0
3
2
0
3
1
EXTEND¶
This method is used to append new elements to a Nested Table or a Varray. It has three possible variants:
.EXTEND inserts a null element.
.EXTEND(n) inserts ‘n’ null elements.
.EXTEND(n, i) inserts ‘n’ copies of the element at ‘i’.
Oracle¶
CREATE OR REPLACE PROCEDURE collection_extend
IS
TYPE varray_typ IS VARRAY(5) OF INTEGER;
TYPE nt_typ IS TABLE OF INTEGER;
nt_variable1 nt_typ := nt_typ(1, 2, 3, 4);
varray_variable1 varray_typ := varray_typ(1, 2, 3);
varray_variable2 varray_typ := varray_typ(1, 2, 3);
BEGIN
nt_variable1.EXTEND;
varray_variable1.EXTEND(2);
varray_variable2.EXTEND(2, 1);
DBMS_OUTPUT.PUT_LINE(nt_variable1.COUNT);
DBMS_OUTPUT.PUT_LINE(varray_variable1.COUNT);
DBMS_OUTPUT.PUT_LINE(varray_variable2.COUNT);
END;
/
CALL collection_extend();
DBMS OUTPUT
-----------
5
5
5
Snowflake¶
Note
Note that a UDF was added to implement the functionality for the update of the element.
This UDF will be added in later revisions.
CREATE OR REPLACE PROCEDURE PUBLIC.collection_first_last()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
nt_variable1 ARRAY := ARRAY_CONSTRUCT(1, 2, 3, 4);
varray_variable1 ARRAY := ARRAY_CONSTRUCT(1, 2, 3);
varray_variable2 ARRAY := ARRAY_CONSTRUCT(1, 2, 3);
BEGIN
nt_variable1 := ARRAY_EXTEND_UDF(nt_variable);
varray_variable1 := ARRAY_EXTEND_UDF(varray_variable1, 2);
varray_variable2 := ARRAY_EXTEND_UDF(varray_variable2, 2, 1);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(nt_variable1);
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(varray_variable1));
CALL DBMS_OUTPUT.PUT_LINE(ARRAY_SIZE(varray_variable2));
END;
$$;
CALL PUBLIC.collection_first_last();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
DBMS OUTPUT
-----------
5
5
5
TRIM¶
This method is used to remove the last elements from a Nested Table or a Varray. It has two possible variants:
.TRIM removes the last element.
.TRIM(n) removes the last ‘n’ elements.
Note
This functionality may be implemented using ARRAY_SLICE
Oracle¶
CREATE OR REPLACE PROCEDURE collection_trim
IS
TYPE varray_typ IS VARRAY(5) OF INTEGER;
TYPE nt_typ IS TABLE OF INTEGER;
varray_variable1 varray_typ := varray_typ(1, 2, 3);
nt_variable1 nt_typ := nt_typ(1, 2, 3, 4);
BEGIN
varray_variable1.TRIM;
nt_variable1.TRIM(2);
DBMS_OUTPUT.PUT_LINE(nt_variable1.COUNT);
DBMS_OUTPUT.PUT_LINE(varray_variable1.COUNT);
END;
/
CALL collection_trim();
DBMS OUTPUT
-----------
2
2
LIMIT¶
This method returns the maximum limit of a Varray.
This method is not supported in Snowflake.
Oracle
CREATE OR REPLACE PROCEDURE collection_limit
IS
TYPE varray_typ1 IS VARRAY(5) OF INTEGER;
TYPE varray_typ2 IS VARRAY(6) OF INTEGER;
varray_variable1 varray_typ1 := varray_typ1(1, 2, 3);
varray_variable2 varray_typ2 := varray_typ2(1, 2, 3, 4);
BEGIN
DBMS_OUTPUT.PUT_LINE(varray_variable1.LIMIT);
DBMS_OUTPUT.PUT_LINE(varray_variable2.LIMIT);
END;
/
CALL collection_limit();
DBMS OUTPUT
-----------
5
6
PRIOR/NEXT
This method returns the prior/next index, given an index. If there is not a prior/next then it returns null. It is most frequently used to traverse a collection.
Oracle
CREATE OR REPLACE PROCEDURE collection_prior_next
IS
TYPE varray_typ1 IS VARRAY(5) OF INTEGER;
TYPE aa_typ IS TABLE OF INTEGER INDEX BY VARCHAR2(20);
varray_variable1 varray_typ1 := varray_typ1(-1, -2, -3);
associative_array1 aa_typ := aa_typ('abc'=>1, 'def'=>2, 'ghi'=>3, 'jkl'=>4);
BEGIN
DBMS_OUTPUT.PUT_LINE(varray_variable1.PRIOR(1));
DBMS_OUTPUT.PUT_LINE(varray_variable1.PRIOR(2));
DBMS_OUTPUT.PUT_LINE(varray_variable1.NEXT(2));
DBMS_OUTPUT.PUT_LINE(varray_variable1.NEXT(3));
DBMS_OUTPUT.PUT_LINE(associative_array1.PRIOR('abc'));
DBMS_OUTPUT.PUT_LINE(associative_array1.PRIOR('def'));
DBMS_OUTPUT.PUT_LINE(associative_array1.NEXT('ghi'));
DBMS_OUTPUT.PUT_LINE(associative_array1.NEXT('jkl'));
DBMS_OUTPUT.PUT_LINE(associative_array1.PRIOR('not found'));
END;
/
CALL collection_prior_next();
DBMS OUTPUT
-----------
-- Empty spaces are due to null results
1
3
abc
jkl
jkl
Known Issues
1. Limit method is not supported in Snowflake
Snowflake does not have support for limited-space varrays. For this reason, this method is not supported.
Related EWIs
No EWIs related.
Nested Table Array Type Definition
Warning
This section is a work in progress, information may change in the future.
Note
This section is for the PL/SQL Version of the Nested Table Arrays, for the Standalone Version please see Nested Table Type Definition.
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
In the database, a nested table is a column type that stores an unspecified number of rows in no particular order.
When you retrieve a nested table value from the database into a PL/SQL nested table variable, PL/SQL gives the rows consecutive indexes, starting at 1. Using these indexes, you can access the individual rows of the nested table variable. The syntax is variable_name(index)
. The indexes and row order of a nested table might not remain stable as you store and retrieve the nested table from the database.
(Oracle PL/SQL Language Reference NESTED TABLES)
For the translation, the type definition is replaced by an ARRAY Semi-structured Data Type and then its usages are changed accordingly across any operations. Please note how the translation for Nested Tables and Varrays are the same.
In order to define a Nested Table Array type, the syntax is as follows:
type_definition := TYPE IS TABLE OF datatype;
To declare a variable of this type:
variable_name collection_type;
Sample Source Patterns¶
Nested Table Array definitions¶
This illustrates how to create different nested table arrays, and how to migrate the definitions for the variables.
Oracle¶
CREATE OR REPLACE PROCEDURE nested_table_procedure
IS
TYPE nested_table_array_typ IS TABLE OF INTEGER;
TYPE nested_table_array_typ2 IS TABLE OF DATE;
nested_table_array nested_table_array_typ;
nested_table_array2 nested_table_array_typ2;
BEGIN
NULL;
END;
Snowflake¶
CREATE OR REPLACE PROCEDURE nested_table_procedure()
RETURNS INTEGER
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
-- NO LONGER NEEDED
/*
TYPE associative_array_typ IS TABLE OF INTEGER INDEX BY VARCHAR2(30);
TYPE associative_array_typ2 IS TABLE OF INTEGER INDEX BY PLS_INTEGER;
*/
associative_array ARRAY;
associative_array2 ARRAY;
BEGIN
NULL;
END;
$$;
Nested Table iteration¶
Oracle¶
CREATE OR REPLACE PROCEDURE nested_table_iteration
IS
TYPE nested_table_typ IS TABLE OF INTEGER;
nested_table_variable nested_table_typ := nested_table_typ (10, 20, 30);
BEGIN
FOR i IN 1..nested_table_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(nested_table_variable(i));
END LOOP;
nested_table_variable (1) := 40;
FOR i IN 1..nested_table_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(nested_table_variable(i));
END LOOP;
END;
/
CALL nested_table_iteration();
DBMS OUTPUT
-----------
10
20
30
40
20
30
Snowflake¶
Note
Note that a UDF was added to implement the functionality for the update of the element.
This UDF will be added in later revisions.
CREATE OR REPLACE PROCEDURE PUBLIC.nested_table_iteration()
RETURNS VARCHAR
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
nested_table_variable ARRAY := ARRAY_CONSTRUCT(10, 20, 30);
BEGIN
FOR i IN 1 TO ARRAY_SIZE(nested_table_variable)
LOOP
CALL DBMS_OUTPUT.PUT_LINE(:nested_table_variable[:i-1]);
END LOOP;
nested_table_variable:= INSERT_REPLACE_COLLECTION_ELEMENT_UDF(nested_table_variable, 1, 40);
FOR i IN 1 TO ARRAY_SIZE(nested_table_variable)
LOOP
CALL DBMS_OUTPUT.PUT_LINE(:nested_table_variable[:i-1]);
END LOOP;
END;
$$;
CALL PUBLIC.nested_table_iteration();
SELECT * FROM DBMS_OUTPUT.DBMS_OUTPUT_LOG;
CREATE OR REPLACE FUNCTION PUBLIC.INSERT_REPLACE_COLLECTION_ELEMENT_UDF(varray ARRAY, position INTEGER, newValue VARIANT)
RETURNS ARRAY
LANGUAGE SQL
AS
$$
ARRAY_CAT(
ARRAY_APPEND(ARRAY_SLICE(varray, 0, (position)-1), newValue),
ARRAY_SLICE(varray, position, ARRAY_SIZE(varray)))
$$;
DBMS OUTPUT
-----------
10
20
30
40
20
30
Known Issues¶
1. They are currently not being converted¶
SnowConvert does not support translating these elements.
2. Indexing needs to be modified¶
Oracle’s indexes start at 1, on Snowflake they will begin at 0.
Related EWIs¶
No EWIs related.
Record Type Definition¶
Warning
This section is a work in progress, information may change in the future.
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
A record variable is a composite variable whose internal components, called fields, can have different data types. The value of a record variable and the values of its fields can change.
You reference an entire record variable by its name. You reference a record field with the syntax record.field
.
You can create a record variable in any of these ways:
Define a record type and then declare a variable of that type.
Use
%ROWTYPE
to declare a record variable that represents either a full or partial row of a database table or view.Use
%TYPE
to declare a record variable of the same type as a previously declared record variable.
(Oracle PL/SQL Language Reference RECORD VARIABLES)
For the translation, the type definition is replaced by an OBJECT Semi-structured Data Type and then its usages are changed accordingly across any operations.
In order to define a Record type, the syntax is as follows:
type_definition := TYPE IS RECORD ( field_definition [, field_definition...] );
field_definition := field_name datatype [ { [NOT NULL default ] | default } ]
default := [ { := | DEFAULT } expression]
To declare a variable of this type:
variable_name { record_type
| rowtype_attribute
| record_variable%TYPE
};
Sample Source Patterns¶
Note
Some parts in the output code are omitted for clarity reasons.
Record initialization and assignment¶
This sample attempts to insert two new rows using a record variable which is reassigned mid-procedure.
Oracle¶
CREATE TABLE record_table(col1 FLOAT, col2 INTEGER);
CREATE OR REPLACE PROCEDURE record_procedure
IS
TYPE record_typ IS RECORD(col1 INTEGER, col2 FLOAT);
record_variable record_typ := record_typ(1, 1.5);--initialization
BEGIN
INSERT INTO record_table(col1, col2)
VALUES (record_variable.col2, record_variable.col1);--usage
--reassignment of properties
record_variable.col1 := 2;
record_variable.col2 := 2.5;
INSERT INTO record_table(col1, col2)
VALUES (record_variable.col2, record_variable.col1);--usage
END;
CALL record_procedure();
SELECT * FROM record_table;
|COL1|COL2|
|----+----|
| 1.5| 1|
| 2.5| 2|
Snowflake¶
Notice how the reassignments are replaced by an OBJECT_INSERT that updates if the column already exists, and how the VALUES clause is replaced by a SELECT.
CREATE OR REPLACE TABLE record_table (col1 FLOAT,
col2 INTEGER)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE record_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
!!!RESOLVE EWI!!! /*** SSC-EWI-0056 - CUSTOM TYPES ARE NOT SUPPORTED IN SNOWFLAKE BUT REFERENCES TO THIS CUSTOM TYPE WERE CHANGED TO OBJECT ***/!!!
TYPE record_typ IS RECORD(col1 INTEGER, col2 FLOAT);
record_variable OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - record_typ DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT('COL1', 1, 'COL2', 1.5);--initialization
BEGIN
INSERT INTO record_table(col1, col2)
SELECT
:record_variable:COL2,
:record_variable:COL1;--usage
--reassignment of properties
record_variable := OBJECT_INSERT(record_variable, 'COL1', 2, true);
record_variable := OBJECT_INSERT(record_variable, 'COL2', 2.5, true);
INSERT INTO record_table(col1, col2)
SELECT
:record_variable:COL2,
:record_variable:COL1;--usage
END;
$$;
CALL record_procedure();
SELECT * FROM
record_table;
COL1|COL2|
----+----+
1.5| 1|
2.5| 2|
%ROWTYPE Record and Values Record¶
Since the operations are the ones that define the structure, these definitions can be replaced by an OBJECT datatype, but the values of the record need to be decomposed as inserting the record “as-is” is not supported.
Oracle¶
CREATE TABLE record_table(col1 INTEGER, col2 VARCHAR2(50), col3 DATE);
CREATE OR REPLACE PROCEDURE insert_record
IS
record_variable record_table%ROWTYPE;
BEGIN
record_variable.col1 := 1;
record_variable.col2 := 'Hello';
record_variable.col3 := DATE '2020-12-25';
INSERT INTO record_table VALUES record_variable;
END;
CALL insert_record();
SELECT * FROM record_table;
|COL1| COL2| COL3|
|----+-------|---------|
| 1|"Hello"|25-DEC-20|
Snowflake¶
Please note finally how the OBJECT variable needs to be initialized in order to add the information to it.
CREATE OR REPLACE TABLE record_table (col1 INTEGER,
col2 VARCHAR(50),
col3 TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE PROCEDURE insert_record ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
record_variable OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWTYPE DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
BEGIN
record_variable := OBJECT_INSERT(record_variable, 'COL1', 1, true);
record_variable := OBJECT_INSERT(record_variable, 'COL2', 'Hello', true);
record_variable := OBJECT_INSERT(record_variable, 'COL3', DATE '2020-12-25', true);
INSERT INTO record_table
SELECT
:record_variable:COL1,
:record_variable:COL2,
:record_variable:COL3;
END;
$$;
CALL insert_record();
SELECT * FROM
record_table;
|COL1| COL2| COL3|
|----+-------|---------|
| 1|"Hello"|25-DEC-20|
Fetching data into a Record¶
Oracle¶
CREATE TABLE record_table(col1 INTEGER, col2 VARCHAR2(50), col3 DATE);
INSERT INTO record_table(col1, col2 , col3)
VALUES (1, 'Hello', DATE '2020-12-25');
CREATE OR REPLACE PROCEDURE load_cursor_record
IS
CURSOR record_cursor IS
SELECT *
FROM record_table;
record_variable record_cursor%ROWTYPE;
BEGIN
OPEN record_cursor;
LOOP
FETCH record_cursor INTO record_variable;
EXIT WHEN record_cursor%NOTFOUND;
DBMS_OUTPUT.PUT_LINE(record_variable.col1);
DBMS_OUTPUT.PUT_LINE(record_variable.col2);
DBMS_OUTPUT.PUT_LINE(record_variable.col3);
END LOOP;
CLOSE record_cursor;
END;
CALL load_cursor_record();
DBMS OUTPUT
-----------
1
Hello
25-DEC-20
Snowflake¶
Please note the additional OBJECT_CONSTRUCT in the Cursor definition, this is what allows to extract an OBJECT, which then can be used to seamlessly migrate the FETCH statement.
CREATE OR REPLACE TABLE record_table (col1 INTEGER,
col2 VARCHAR(50),
col3 TIMESTAMP /*** SSC-FDM-OR0042 - DATE TYPE COLUMN HAS A DIFFERENT BEHAVIOR IN SNOWFLAKE. ***/
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
;
INSERT INTO record_table(col1, col2 , col3)
VALUES (1, 'Hello', DATE '2020-12-25');
CREATE OR REPLACE PROCEDURE load_cursor_record ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
record_cursor CURSOR
FOR
SELECT
OBJECT_CONSTRUCT( *) sc_cursor_record
FROM
record_table;
record_variable OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWTYPE DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
BEGIN
OPEN record_cursor;
LOOP
--** SSC-PRF-0003 - FETCH INSIDE A LOOP IS CONSIDERED A COMPLEX PATTERN, THIS COULD DEGRADE SNOWFLAKE PERFORMANCE. **
FETCH record_cursor INTO
:record_variable;
IF (record_variable IS NULL) THEN
EXIT;
END IF;
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(:record_variable:COL1);
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(:record_variable:COL2);
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(:record_variable:COL3::DATE);
END LOOP;
CLOSE record_cursor;
END;
$$;
CALL load_cursor_record();
DBMS OUTPUT
-----------
1
Hello
25-DEC-20
Assigning a Record Variable in a SELECT INTO¶
This transformation consists in taking advantage of the OBJECT_CONTRUCT function to initialize the record using the SELECT columns as the arguments.
Sample auxiliary code¶
create table sample_table(ID number, NAME varchar2(23));
CREATE TABLE RESULTS (COL1 VARCHAR(20), COL2 VARCHAR(40));
insert into sample_table values(1, 'NAME 1');
insert into sample_table values(2, 'NAME 2');
insert into sample_table values(3, 'NAME 3');
insert into sample_table values(4, 'NAME 4');
CREATE OR REPLACE TABLE sample_table (ID NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
NAME VARCHAR(23))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
CREATE OR REPLACE TABLE RESULTS (COL1 VARCHAR(20),
COL2 VARCHAR(40))
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
insert into sample_table
values(1, 'NAME 1');
insert into sample_table
values(2, 'NAME 2');
insert into sample_table
values(3, 'NAME 3');
insert into sample_table
values(4, 'NAME 4');
Oracle¶
CREATE OR REPLACE PROCEDURE sp_sample1 AS
-- Rowtype variable
rowtype_variable sample_table%rowtype;
--Record variable
TYPE record_typ_def IS RECORD(ID number, NAME varchar2(23));
record_variable_def record_typ_def;
-- Auxiliary variable
name_var VARCHAR(20);
BEGIN
SELECT * INTO rowtype_variable FROM sample_table WHERE ID = 1 FETCH NEXT 1 ROWS ONLY;
name_var := rowtype_variable.NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 1', name_var);
SELECT ID, NAME INTO rowtype_variable FROM sample_table WHERE ID = 2 FETCH NEXT 1 ROWS ONLY;
name_var := rowtype_variable.NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 2', name_var);
SELECT * INTO record_variable_def FROM sample_table WHERE ID = 3 FETCH NEXT 1 ROWS ONLY;
name_var := record_variable_def.NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 3', name_var);
SELECT ID, NAME INTO record_variable_def FROM sample_table WHERE ID = 4 FETCH NEXT 1 ROWS ONLY;
name_var := record_variable_def.NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 4', name_var);
END;
call sp_sample1();
SELECT * FROM results;
|COL1 |COL2 |
|--------|------|
|SELECT 1|NAME 1|
|SELECT 2|NAME 2|
|SELECT 3|NAME 3|
|SELECT 4|NAME 4|
Snowflake¶
CREATE OR REPLACE PROCEDURE sp_sample1 ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
-- Rowtype variable
rowtype_variable OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - ROWTYPE DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
--Record variable
!!!RESOLVE EWI!!! /*** SSC-EWI-0056 - CUSTOM TYPES ARE NOT SUPPORTED IN SNOWFLAKE BUT REFERENCES TO THIS CUSTOM TYPE WERE CHANGED TO OBJECT ***/!!!
TYPE record_typ_def IS RECORD(ID number, NAME varchar2(23));
record_variable_def OBJECT !!!RESOLVE EWI!!! /*** SSC-EWI-0036 - record_typ_def DATA TYPE CONVERTED TO OBJECT ***/!!! := OBJECT_CONSTRUCT();
-- Auxiliary variable
name_var VARCHAR(20);
BEGIN
SELECT
OBJECT_CONSTRUCT( *) INTO
:rowtype_variable
FROM
sample_table
WHERE ID = 1
FETCH NEXT 1 ROWS ONLY;
name_var := :rowtype_variable:NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 1', :name_var);
SELECT
OBJECT_CONSTRUCT()
INTO
:rowtype_variable
FROM
sample_table
WHERE ID = 2
FETCH NEXT 1 ROWS ONLY;
name_var := :rowtype_variable:NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 2', :name_var);
SELECT
OBJECT_CONSTRUCT( *) INTO
:record_variable_def
FROM
sample_table
WHERE ID = 3
FETCH NEXT 1 ROWS ONLY;
name_var := :record_variable_def:NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 3', :name_var);
SELECT
OBJECT_CONSTRUCT('ID', ID, 'NAME', NAME) INTO
:record_variable_def
FROM
sample_table
WHERE ID = 4
FETCH NEXT 1 ROWS ONLY;
name_var := :record_variable_def:NAME;
INSERT INTO RESULTS(COL1, COL2) VALUES('SELECT 4', :name_var);
END;
$$;
call sp_sample1();
SELECT * FROM
results;
|COL1 |COL2 |
|--------|------|
|SELECT 1|NAME 1|
|SELECT 2|NAME 2|
|SELECT 3|NAME 3|
|SELECT 4|NAME 4|
Known Issues¶
1. The following functionalities are currently not being converted:¶
Fetching data into a Record.
Nested records (Records inside records).
Collections inside records.
Related EWIs¶
SSC-EWI-0036: Data type converted to another data type.
SSC-EWI-0056: Create Type Not Supported
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-OR0042: Date Type Transformed To Timestamp Has A Different Behavior.
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
SSC-PRF-0003: Fetch inside a loop is considered a complex pattern, this could degrade Snowflake performance.
Varray Type Definition¶
Warning
This section is a work in progress, information may change in the future.
Note
This section is for the PL/SQL Version of the Varrays, for the Standalone Version please see Array Type Definition.
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
A varray (variable-size array) is an array whose number of elements can vary from zero (empty) to the declared maximum size.
To access an element of a varray variable, use the syntax variable_name(index)
. The lower bound of index
is 1; the upper bound is the current number of elements. The upper bound changes as you add or delete elements, but it cannot exceed the maximum size. When you store and retrieve a varray from the database, its indexes and element order remain stable.
(Oracle PL/SQL Language Reference VARRAYS)
For the translation, the type definition is replaced by an ARRAY Semi-structured Data Type and then its usages are changed accordingly across any operations. Please note how the translation for Nested Tables and Varrays are the same.
In order to define a varray type, the syntax is as follows:
type_definition := { VARRAY | [VARYING] ARRAY } (size_limit) OF datatype
[NOT NULL];
To declare a variable of this type:
variable_name collection_type;
Sample Source Patterns¶
Varray definitions¶
This illustrates how three different ways to create a varray, and how to migrate these definitions for the variables.
Oracle¶
CREATE OR REPLACE PROCEDURE associative_array_procedure
IS
TYPE varray_typ IS ARRAY(10) OF INTEGER;
TYPE varray_typ2 IS VARRAY(10) OF INTEGER;
TYPE varray_typ3 IS VARYING ARRAY(10) OF INTEGER;
array_variable varray_typ;
array_variable2 varray_typ2;
array_variable3 varray_typ3;
BEGIN
NULL;
END;
Snowflake¶
CREATE OR REPLACE PROCEDURE associative_array_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE varray_typ IS ARRAY(10) OF INTEGER;
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE varray_typ2 IS VARRAY(10) OF INTEGER;
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE varray_typ3 IS VARYING ARRAY(10) OF INTEGER;
array_variable VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'varray_typ' USAGE CHANGED TO VARIANT ***/!!!;
array_variable2 VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'varray_typ2' USAGE CHANGED TO VARIANT ***/!!!;
array_variable3 VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'varray_typ3' USAGE CHANGED TO VARIANT ***/!!!;
BEGIN
NULL;
END;
$$;
Varray iteration¶
Oracle¶
CREATE OR REPLACE PROCEDURE varray_iteration
IS
TYPE varray_typ IS VARRAY(3) OF INTEGER;
varray_variable varray_typ := varray_typ(10, 20, 30);
BEGIN
FOR i IN 1..varray_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(varray_variable(i));
END LOOP;
varray_variable(1) := 40;
FOR i IN 1..varray_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(varray_variable(i));
END LOOP;
END;
/
CALL varray_iteration();
DBMS OUTPUT
-----------
10
20
30
40
20
30
Snowflake¶
Note
Note that a UDF was added to implement the functionality for the update of the element.
This UDF will be added in later revisions.
CREATE OR REPLACE PROCEDURE varray_iteration ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE varray_typ IS VARRAY(3) OF INTEGER;
varray_variable VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'varray_typ' USAGE CHANGED TO VARIANT ***/!!! := varray_typ(10, 20, 30);
BEGIN
FOR i IN 1 TO 0 /*varray_variable.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'VARRAY CUSTOM TYPE EXPRESSION' NODE ***/!!! LOOP
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(varray_variable(i));
END LOOP;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0108 - THE FOLLOWING ASSIGNMENT STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
varray_variable(1) := 40;
FOR i IN 1 TO 0 /*varray_variable.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'VARRAY CUSTOM TYPE EXPRESSION' NODE ***/!!! LOOP
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(varray_variable(i));
END LOOP;
END;
$$;
CALL varray_iteration();
CREATE OR REPLACE FUNCTION PUBLIC.INSERT_REPLACE_COLLECTION_ELEMENT_UDF(varray ARRAY, position INTEGER, newValue VARIANT)
RETURNS ARRAY
LANGUAGE SQL
AS
$$
ARRAY_CAT(
ARRAY_APPEND(ARRAY_SLICE(varray, 0, (position)-1), newValue),
ARRAY_SLICE(varray, position, ARRAY_SIZE(varray)))
$$;
DBMS OUTPUT
-----------
10
20
30
40
20
30
Known Issues¶
1. They are currently not being converted¶
SnowConvert does not support translating these elements.
2. Indexing needs to be modified¶
Oracle’s indexes start at 1, on Snowflake they will begin at 0.
3. Array Density may not match the original¶
Since the ARRAY datatype can become sparse, care should be taken when performing additions or deletions of the array. Using ARRAY_COMPACT() after such operations can be helpful if the density is a concern.
Related EWIs¶
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-0073: Pending Functional Equivalence Review.
SSC-EWI-OR0108: The Following Assignment Statement is Not Supported by Snowflake Scripting.
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
Collection Bulk Operations¶
Warning
This section is a work in progress, information may change in the future
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
The BULK
COLLECT
clause, a feature of bulk SQL, returns results from SQL to PL/SQL in batches rather than one at a time.
The BULK
COLLECT
clause can appear in:
SELECT
INTO
statementFETCH
statementRETURNING
INTO
clause of:DELETE
statementINSERT
statementUPDATE
statementEXECUTE
IMMEDIATE
statement
With the BULK
COLLECT
clause, each of the preceding statements retrieves an entire result set and stores it in one or more collection variables in a single operation (which is more efficient than using a loop statement to retrieve one result row at a time).
(Oracle PL/SQL Language Reference BULK COLLECT CLAUSE)
This section has some workarounds for SELECTs and FETCH Cursor with Bulk Clauses.
Sample Source Patterns¶
Source Table¶
Oracle¶
CREATE TABLE bulk_collect_table(col1 INTEGER);
INSERT INTO bulk_collect_table VALUES(1);
INSERT INTO bulk_collect_table VALUES(2);
INSERT INTO bulk_collect_table VALUES(3);
INSERT INTO bulk_collect_table VALUES(4);
INSERT INTO bulk_collect_table VALUES(5);
INSERT INTO bulk_collect_table VALUES(6);
Snowflake¶
CREATE OR REPLACE TABLE bulk_collect_table (col1 INTEGER)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
INSERT INTO bulk_collect_table
VALUES(1);
INSERT INTO bulk_collect_table
VALUES(2);
INSERT INTO bulk_collect_table
VALUES(3);
INSERT INTO bulk_collect_table
VALUES(4);
INSERT INTO bulk_collect_table
VALUES(5);
INSERT INTO bulk_collect_table
VALUES(6);
Bulk Collect from a Table¶
Oracle¶
CREATE OR REPLACE PROCEDURE bulk_collect_procedure
IS
CURSOR record_cursor IS
SELECT *
FROM bulk_collect_table;
TYPE fetch_collection_typ IS TABLE OF record_cursor%ROWTYPE;
fetch_collection_variable fetch_collection_typ;
TYPE collection_typ IS TABLE OF bulk_collect_table%ROWTYPE;
collection_variable collection_typ;
BEGIN
SELECT * BULK COLLECT INTO collection_variable FROM bulk_collect_table;
FOR i IN 1..collection_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(collection_variable(i).col1);
END LOOP;
collection_variable := null;
OPEN record_cursor;
FETCH record_cursor BULK COLLECT INTO collection_variable;
CLOSE record_cursor;
FOR i IN 1..collection_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(collection_variable(i).col1+6);
END LOOP;
collection_variable := null;
EXECUTE IMMEDIATE 'SELECT * FROM bulk_collect_table' BULK COLLECT INTO collection_variable;
FOR i IN 1..collection_variable.COUNT
LOOP
DBMS_OUTPUT.PUT_LINE(collection_variable(i).col1+12);
END LOOP;
END;
/
CALL bulk_collect_procedure();
DBMS OUTPUT
-----------
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
Snowflake¶
EXECUTE IMMEDIATE with Bulk Collect clause has no workarounds offered.
Note
Please note, that while the FETCH Cursor can be mostly preserved, it is advised to be changed into SELECT statements whenever possible for performance issues.
CREATE OR REPLACE PROCEDURE bulk_collect_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
record_cursor CURSOR
FOR
SELECT *
FROM
bulk_collect_table;
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE fetch_collection_typ IS TABLE OF record_cursor%ROWTYPE;
fetch_collection_variable VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'fetch_collection_typ' USAGE CHANGED TO VARIANT ***/!!!;
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE collection_typ IS TABLE OF bulk_collect_table%ROWTYPE;
collection_variable VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'collection_typ' USAGE CHANGED TO VARIANT ***/!!!;
BEGIN
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'RECORDS AND COLLECTIONS' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
SELECT * BULK COLLECT INTO collection_variable FROM bulk_collect_table;
FOR i IN 1 TO 0 /*collection_variable.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'NESTED TABLE CUSTOM TYPE EXPRESSION' NODE ***/!!! LOOP
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(:collection_variable(i).col1);
END LOOP;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0108 - THE FOLLOWING ASSIGNMENT STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
collection_variable := null;
OPEN record_cursor;
--** SSC-PRF-0001 - THIS STATEMENT HAS USAGES OF CURSOR FETCH BULK OPERATIONS **
record_cursor := (
CALL FETCH_BULK_COLLECTION_RECORDS_UDF(:record_cursor)
);
collection_variable := :record_cursor:RESULT;
CLOSE record_cursor;
FOR i IN 1 TO 0 /*collection_variable.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'NESTED TABLE CUSTOM TYPE EXPRESSION' NODE ***/!!! LOOP
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '+' MAY NOT BEHAVE CORRECTLY BETWEEN unknown AND Number ***/!!!
:collection_variable(i).col1+6);
END LOOP;
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0108 - THE FOLLOWING ASSIGNMENT STATEMENT IS NOT SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
collection_variable := null;
!!!RESOLVE EWI!!! /*** SSC-EWI-0030 - THE STATEMENT BELOW HAS USAGES OF DYNAMIC SQL. ***/!!!
EXECUTE IMMEDIATE 'SELECT * FROM
bulk_collect_table'
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'EXECUTE IMMEDIATE RETURNING CLAUSE' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
BULK COLLECT INTO collection_variable;
FOR i IN 1 TO 0 /*collection_variable.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'NESTED TABLE CUSTOM TYPE EXPRESSION' NODE ***/!!! LOOP
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF(
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '+' MAY NOT BEHAVE CORRECTLY BETWEEN unknown AND Number ***/!!!
:collection_variable(i).col1+12);
END LOOP;
END;
$$;
CALL bulk_collect_procedure();
DBMS OUTPUT
-----------
1
2
3
4
5
6
7
8
9
10
11
-- EXECUTE IMMEDIATE NOT EXECUTED, it's not supported
SELECT INTO statement case¶
In this case, the translation specification uses RESULTSETs. Review the documentation for WITH, SELECT, and BULK COLLECT INTO statements here:
Known Issues¶
1. Heavy performance issues on FETCH Cursor workaround¶
The workaround for the Fetch cursor has heavy performance requirements due to the Temporary table. It is advised for them to be manually migrated to SELECT statements
2. Execute immediate statements are not transformed¶
They are not supported by SnowConvert but may be manually changed to SELECT statements.
Related EWIs¶
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-0073: Pending Functional Equivalence Review
SSC-EWI-OR0036: Types resolution issues, the arithmetic operation may not behave correctly between string and date.
SSC-EWI-OR0108: The Following Assignment Statement is Not Supported by Snowflake Scripting.
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
SSC-PRF-0001: This statement has usages of cursor fetch bulk operations.
SSC-EWI-0030: The statement below has usages of dynamic SQL
WITH, SELECT, and BULK COLLECT INTO statements¶
This section is a translation specification. Information may change in the future.
Note
Some parts in the output code are omitted for clarity reasons.
Description¶
This section is a translation specification for the statement WITH subsequent to a SELECT statement which uses a BULK COLLECT INTO statement. For more information review the following documentation:
Sample Source Patterns¶
Note
Some parts in the output code are omitted for clarity reasons.
The following query is used for the following examples.
-- Sample MySampleTable table
CREATE TABLE MySampleTable (
MySampleID NUMBER PRIMARY KEY,
FirstName VARCHAR2(50),
Salary NUMBER,
Department VARCHAR2(50)
);
-- Insert some sample data
INSERT INTO MySampleTable (MySampleID, FirstName, Salary, Department)
VALUES (1, 'Bob One', 50000, 'HR');
INSERT INTO MySampleTable (MySampleID, FirstName, Salary, Department)
VALUES (2, 'Bob Two', 60000, 'HR');
INSERT INTO MySampleTable (MySampleID, FirstName, Salary, Department)
VALUES (3, 'Bob Three', 75000, 'IT');
INSERT INTO MySampleTable (MySampleID, FirstName, Salary, Department)
VALUES (4, 'Bob Four', 80000, 'IT');
-- Sample MySampleTable table
CREATE OR REPLACE TABLE MySampleTable (
MySampleID NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/ PRIMARY KEY,
FirstName VARCHAR(50),
Salary NUMBER(38, 18) /*** SSC-FDM-0006 - NUMBER TYPE COLUMN MAY NOT BEHAVE SIMILARLY IN SNOWFLAKE. ***/,
Department VARCHAR(50)
)
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
;
-- Insert some sample data
INSERT INTO MySampleTable(MySampleID, FirstName, Salary, Department)
VALUES (1, 'Bob One', 50000, 'HR');
INSERT INTO MySampleTable(MySampleID, FirstName, Salary, Department)
VALUES (2, 'Bob Two', 60000, 'HR');
INSERT INTO MySampleTable(MySampleID, FirstName, Salary, Department)
VALUES (3, 'Bob Three', 75000, 'IT');
INSERT INTO MySampleTable(MySampleID, FirstName, Salary, Department)
VALUES (4, 'Bob Four', 80000, 'IT');
1. Inside procedure simple case¶
This is an approach that uses a resultset data type. User-defined types must be reviewed. Review the following Snowflake documentation to review more information about RESULTSETs.
The following example uses a User-defined type and it is declared indirectly as a table. The translation for this case implements a RESULTSET as a data type in Snowflake. The resultset is stored on a variable which must be returned wrapped on a TABLE()
function.
Oracle
-- Additional Params: -t JavaScript
CREATE OR REPLACE PROCEDURE simple_procedure
IS
TYPE salary_collection IS TABLE OF NUMBER;
v_salaries salary_collection := salary_collection();
BEGIN
WITH IT_Employees AS (
SELECT Salary
FROM MySampleTable
WHERE Department = 'IT'
)
SELECT Salary BULK COLLECT INTO v_salaries
FROM IT_Employees;
END;
CALL simple_procedure();
Note
The query does not return results but the expected gathered information would be the IT Salary Information used for the example:
IT_Salary |
---|
75000 |
80000 |
One of the limitations of the RESULTSETs is that they cannot be used as tables. E.g.: select * from my_result_set;
(This is an error, review the following documentation for more information).
Snowflake Scripting
CREATE OR REPLACE PROCEDURE simple_procedure ()
RETURNS STRING
LANGUAGE JAVASCRIPT
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},{"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
// SnowConvert Helpers Code section is omitted.
/* ** SSC-EWI-OR0072 - PROCEDURAL MEMBER TYPE DEFINITION NOT SUPPORTED. ** */
/* TYPE salary_collection IS TABLE OF NUMBER */
;
/* ** SSC-EWI-OR0104 - UNUSABLE VARIABLE, ITS TYPE WAS NOT TRANSFORMED ** */
/* v_salaries salary_collection := salary_collection() */
;
// WITH IT_Employees AS (
// SELECT Salary
// FROM MySampleTable
// WHERE Department = 'IT'
// )
// SELECT Salary BULK COLLECT INTO v_salaries
// FROM IT_Employees
!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'WithCte' NODE ***/!!!
null
$$;
CALL simple_procedure();
SALARY |
---|
77500 |
80000 |
2. Simple case for iterations: FOR LOOP statement
The following case is to define a translation for iteration with FOR...LOOP
. In this case, the User-defined type is implicitly a table, thus, it is possible to use a cursor to iterate. Review the following documentation to learn more:
Snowflake documentation about Returning a Table for a Cursor.
In this case, there is a need to create a cursor for the iteration. Review the following Cursor Assignment Syntax documentation.
Oracle
CREATE OR REPLACE PROCEDURE simple_procedure
IS
TYPE salary_collection IS TABLE OF NUMBER;
v_salaries salary_collection := salary_collection();
v_average_salary NUMBER;
salaries_count NUMBER;
BEGIN
salaries_count := 0;
WITH IT_Employees AS (
SELECT Salary
FROM MySampleTable
WHERE Department = 'IT'
)
SELECT Salary BULK COLLECT INTO v_salaries
FROM IT_Employees;
-- Calculate the average salary
IF v_salaries.COUNT > 0 THEN
v_average_salary := 0;
FOR i IN 1..v_salaries.COUNT LOOP
v_average_salary := v_average_salary + v_salaries(i);
salaries_count := salaries_count + 1;
END LOOP;
v_average_salary := v_average_salary / salaries_count;
END IF;
-- Display the average salary
DBMS_OUTPUT.PUT_LINE('Average Salary for IT Department: ' || v_average_salary);
END;
/
CALL simple_procedure();
Statement processed.
Average Salary for IT Department: 77500
Snowflake Scripting
CREATE OR REPLACE PROCEDURE simple_procedure ()
RETURNS VARCHAR
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"oracle"}}'
EXECUTE AS CALLER
AS
$$
DECLARE
-- !!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'PL COLLECTION TYPE DEFINITION' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
-- TYPE salary_collection IS TABLE OF NUMBER;
v_salaries VARIANT !!!RESOLVE EWI!!! /*** SSC-EWI-0062 - CUSTOM TYPE 'salary_collection' USAGE CHANGED TO VARIANT ***/!!! := salary_collection();
v_average_salary NUMBER(38, 18);
salaries_count NUMBER(38, 18);
BEGIN
salaries_count := 0;
WITH IT_Employees AS
(
SELECT Salary
FROM
MySampleTable
WHERE Department = 'IT'
)
!!!RESOLVE EWI!!! /*** SSC-EWI-0058 - FUNCTIONALITY FOR 'RECORDS AND COLLECTIONS' IS NOT CURRENTLY SUPPORTED BY SNOWFLAKE SCRIPTING ***/!!!
SELECT Salary BULK COLLECT INTO v_salaries
FROM IT_Employees;
-- Calculate the average salary
IF (null /*v_salaries.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'NESTED TABLE CUSTOM TYPE EXPRESSION' NODE ***/!!! > 0) THEN
v_average_salary := 0;
FOR i IN 1 TO 0 /*v_salaries.COUNT*/!!!RESOLVE EWI!!! /*** SSC-EWI-0073 - PENDING FUNCTIONAL EQUIVALENCE REVIEW FOR 'NESTED TABLE CUSTOM TYPE EXPRESSION' NODE ***/!!! LOOP
v_average_salary :=
!!!RESOLVE EWI!!! /*** SSC-EWI-OR0036 - TYPES RESOLUTION ISSUES, ARITHMETIC OPERATION '+' MAY NOT BEHAVE CORRECTLY BETWEEN ExactNumeric AND salary_collection ***/!!!
:v_average_salary + v_salaries(i);
salaries_count := :salaries_count + 1;
END LOOP;
v_average_salary := :v_average_salary / :salaries_count;
END IF;
-- Display the average salary
--** SSC-FDM-OR0035 - CHECK UDF IMPLEMENTATION FOR DBMS_OUTPUT.PUT_LINE_UDF. **
CALL DBMS_OUTPUT.PUT_LINE_UDF('Average Salary for IT Department: ' || NVL(:v_average_salary :: STRING, ''));
END;
$$;
CALL simple_procedure();
SIMPLE_PROCEDURE |
---|
Average Salary for IT Department: 77500 |
Known Issues
1. Resulset limitations.
There are limitations while using the RESULTSET data type. Review the following Snowflake documentation to learn more. Markable limitations are the following:
Declaring a column of type RESULTSET.
Declaring a parameter of type RESULTSET.
Declaring a stored procedure’s return type as a RESULTSET.
2. Execute statements with Bulk Collect clause are not supported.
Review the following documentation.
Related EWIs
SSC-EWI-0058: Functionality is not currently supported by Snowflake Scripting.
SSC-EWI-0062: Custom type usage changed to variant.
SSC-EWI-0073: Pending Functional Equivalence Review
SSC-EWI-OR0036: Types resolution issues, the arithmetic operation may not behave correctly between string and date.
SSC-EWI-OR0072: Procedural Member not supported
SSC-EWI-OR0104: Unusable collection variable.
SSC-FDM-0006: Number type column may not behave similarly in Snowflake.
SSC-FDM-OR0035: DBMS_OUTPUT.PUTLINE check UDF implementation.
HELPERS
Bulk Cursor Helpers
Note
You might also be interested in Default FORALL transformation.
The Cursor is simulated with an OBJECT
with different information regarding the state of the cursor. A temporary table is created to store the result set of the cursor’s query.
Most of these Procedures return a new Object with the updated state of the cursor.
INIT_CURSOR¶
This function initializes a new object with the basic cursor information
CREATE OR REPLACE FUNCTION INIT_CURSOR(NAME VARCHAR, QUERY VARCHAR)
RETURNS OBJECT
AS
$$
SELECT OBJECT_CONSTRUCT('NAME', NAME, 'ROWCOUNT', -1, 'QUERY', QUERY, 'ISOPEN', FALSE, 'FOUND', NULL, 'NOTFOUND', NULL)
$$;
OPEN_BULK_CURSOR¶
These procedures creates a temporary table with the query of the cursor. An optional overload exists to support bindings.
CREATE OR REPLACE PROCEDURE OPEN_BULK_CURSOR(CURSOR OBJECT, BINDINGS ARRAY)
RETURNS OBJECT
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS
$$
var query = `CREATE OR REPLACE TEMPORARY TABLE ${CURSOR.NAME}_TEMP_TABLE AS ${CURSOR.QUERY}`;
snowflake.execute({ sqlText: query, binds: BINDINGS });
CURSOR.ROWCOUNT = 0;
CURSOR.ISOPEN = true;
return CURSOR;
$$;
CREATE OR REPLACE PROCEDURE OPEN_BULK_CURSOR(CURSOR OBJECT)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL OPEN_BULK_CURSOR(:CURSOR, NULL));
RETURN :RESULT;
END;
$$;
CLOSE_BULK_CURSOR¶
This procedure deletes the temporary table that stored the result set of the cursor and resets the cursor’s properties to their initial state.
CREATE OR REPLACE PROCEDURE CLOSE_BULK_CURSOR(CURSOR OBJECT)
RETURNS OBJECT
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS
$$
var query = `DROP TABLE ${CURSOR.NAME}_TEMP_TABLE`;
snowflake.execute({ sqlText: query });
CURSOR.ROWCOUNT = -1;
CURSOR.ISOPEN = false;
CURSOR.FOUND = null;
CURSOR.NOTFOUND = null;
return CURSOR;
$$;
FETCH Helpers¶
Due to Oracle being capable of doing the FETCH
statement on different kind of scenarios, a multiple procedures with overloads were created to handle each case. These helpers save the fetched values into the RESULT
property in the CURSOR
object.
Some of the overloads include variations when the LIMIT
clause was used or not. Other overloads have a COLUMN_NAMES
argument that is necessary when the FETCH
statement is being done into a variable that has or contains a records with column names that are different to the column names of the query.
FETCH_BULK_COLLECTION_RECORDS¶
These procedures are used when a FETCH BULK
is done into a collection of records.
CREATE OR REPLACE PROCEDURE FETCH_BULK_COLLECTION_RECORDS(CURSOR OBJECT, LIMIT FLOAT, COLUMN_NAMES ARRAY)
RETURNS OBJECT
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS
$$
var objectConstructArgs = [];
if (COLUMN_NAMES) {
for (let i = 0 ; i < COLUMN_NAMES.length ; i++) {
objectConstructArgs.push("'" + COLUMN_NAMES[i] + "'");
objectConstructArgs.push('$' + (i + 1));
}
} else {
objectConstructArgs.push('*');
}
var limitValue = LIMIT ?? 'NULL';
var query = `SELECT ARRAY_AGG(OBJECT_CONSTRUCT(${objectConstructArgs.join(', ')})) FROM (SELECT * FROM ${CURSOR.NAME}_TEMP_TABLE LIMIT ${limitValue} OFFSET ${CURSOR.ROWCOUNT})`;
var stmt = snowflake.createStatement({ sqlText: query});
var resultSet = stmt.execute();
resultSet.next();
CURSOR.RESULT = resultSet.getColumnValue(1);
CURSOR.ROWCOUNT += CURSOR.RESULT.length;
CURSOR.FOUND = CURSOR.RESULT.length > 0;
CURSOR.NOTFOUND = !CURSOR.FOUND;
return CURSOR;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_COLLECTION_RECORDS(CURSOR OBJECT)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_COLLECTION_RECORDS(:CURSOR, NULL, NULL));
RETURN :RESULT;
END;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_COLLECTION_RECORDS(CURSOR OBJECT, LIMIT INTEGER)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_COLLECTION_RECORDS(:CURSOR, :LIMIT, NULL));
RETURN :RESULT;
END;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_COLLECTION_RECORDS(CURSOR OBJECT, COLUMN_NAMES ARRAY)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_COLLECTION_RECORDS(:CURSOR, NULL, :COLUMN_NAMES));
RETURN :RESULT;
END;
$$;
FETCH_BULK_COLLECTIONS¶
These procedures are used when the FETCH
statement is done into one or multiple collections. Since the columns are specified in this FETCH
operation, an override for specific COLUMN_NAMES
is not necessary.
CREATE OR REPLACE PROCEDURE FETCH_BULK_COLLECTIONS(CURSOR OBJECT, LIMIT FLOAT)
RETURNS OBJECT
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS
$$
var limitClause = '';
var limitValue = LIMIT ?? 'NULL';
var query = `SELECT * FROM ${CURSOR.NAME}_TEMP_TABLE LIMIT ${limitValue} OFFSET ${CURSOR.ROWCOUNT}`;
var stmt = snowflake.createStatement({ sqlText: query});
var resultSet = stmt.execute();
var column_count = stmt.getColumnCount();
CURSOR.RESULT = [];
for (let i = 0 ; i < column_count ; i++) {
CURSOR.RESULT[i] = [];
}
while (resultSet.next()) {
for (let i = 1 ; i <= column_count ; i++) {
let columnName = stmt.getColumnName(i);
CURSOR.RESULT[i - 1].push(resultSet.getColumnValue(columnName));
}
}
CURSOR.ROWCOUNT += stmt.getRowCount();
CURSOR.FOUND = stmt.getRowCount() > 0;
CURSOR.NOTFOUND = !CURSOR.FOUND;
return CURSOR;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_COLLECTIONS(CURSOR OBJECT)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_COLLECTIONS(:CURSOR, NULL));
RETURN :RESULT;
END;
$$;
FETCH_BULK_RECORD_COLLECTIONS¶
These procedures are used when a FETCH BULK
is done into a record of collections.
CREATE OR REPLACE PROCEDURE FETCH_BULK_RECORD_COLLECTIONS(CURSOR OBJECT, LIMIT FLOAT, COLUMN_NAMES ARRAY)
RETURNS OBJECT
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS
$$
var limitValue = LIMIT ?? 'NULL';
var query = `SELECT * FROM ${CURSOR.NAME}_TEMP_TABLE LIMIT ${limitValue} OFFSET ${CURSOR.ROWCOUNT}`;
var stmt = snowflake.createStatement({ sqlText: query});
var resultSet = stmt.execute();
var column_count = stmt.getColumnCount();
CURSOR.RESULT = {};
if (COLUMN_NAMES)
{
for (let i = 0 ; i < COLUMN_NAMES.length ; i++) {
CURSOR.RESULT[COLUMN_NAMES[i]] = [];
}
} else {
for (let i = 1 ; i <= column_count ; i++) {
let columnName = stmt.getColumnName(i);
CURSOR.RESULT[columnName] = [];
}
}
while (resultSet.next()) {
for (let i = 1 ; i <= column_count ; i++) {
let columnName = stmt.getColumnName(i);
let fieldName = COLUMN_NAMES ? COLUMN_NAMES[i - 1] : columnName;
CURSOR.RESULT[fieldName].push(resultSet.getColumnValue(columnName));
}
}
CURSOR.ROWCOUNT += stmt.getRowCount();
CURSOR.FOUND = stmt.getRowCount() > 0;
CURSOR.NOTFOUND = !CURSOR.FOUND;
return CURSOR;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_RECORD_COLLECTIONS(CURSOR OBJECT)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_RECORD_COLLECTIONS(:CURSOR, NULL, NULL));
RETURN :RESULT;
END;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_RECORD_COLLECTIONS(CURSOR OBJECT, LIMIT INTEGER)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_RECORD_COLLECTIONS(:CURSOR, :LIMIT, NULL));
RETURN :RESULT;
END;
$$;
CREATE OR REPLACE PROCEDURE FETCH_BULK_RECORD_COLLECTIONS(CURSOR OBJECT, COLUMN_NAMES ARRAY)
RETURNS OBJECT
LANGUAGE SQL
EXECUTE AS CALLER
AS
$$
DECLARE
RESULT OBJECT;
BEGIN
RESULT := (CALL FETCH_BULK_RECORD_COLLECTIONS(:CURSOR, NULL, :COLUMN_NAMES));
RETURN :RESULT;
END;
$$;