SnowConvert - Translation Spec
  • For Teradata
  • Translation Reference
    • Teradata
      • Scripts to Snowflake SQL Translation Reference
        • COMMON STATEMENTS
          • ERROR HANDLING
          • EXIT or QUIT
          • GOTO
          • IF... THEN...
        • BTEQ
        • MLOAD
          • Import
      • Scripts To Python Translation Reference
        • BTEQ
          • REPEAT
          • USING REQUEST MODIFIER
        • FLOAD
          • BEGIN LOADING
        • MLOAD
          • BEGIN MLOAD
        • TPT
        • SnowConvert Scripts Helpers
          • Technical Documentation
      • SQL Translation Reference
        • Built-in Functions
          • CURRENT_TIMESTAMP
          • Cast to DATE using { }
          • Cast to INTERVAL datatype
          • COALESCE
          • DAYNUMBER_OF_MONTH
          • FROM_BYTES
          • GETQUERYBANDVALUE
          • JSON_CHECK
          • JSON_EXTRACT
          • JSON_TABLE
          • NEW JSON
          • NVP
          • OVERLAPS
          • PIVOT
          • P_INTERSECT
          • RANK
          • Regex functions
          • STRTOK_SPLIT_TO_TABLE
          • SUBSTRING
          • TD_UNPIVOT
          • TO_CHAR
          • XMLAGG
        • Database DBC
        • Data Types
        • DDL
          • Tables
            • WITH DEFAULT
          • Index
          • Views
        • DML
          • Delete Statement
          • Insert Statement
            • LOGGING ERRORS
          • Select Statement
            • Expand On Clause
            • Normalize
            • Reset When
          • Set Operators
          • Update Statement
          • With Modifier
        • SnowConvert Procedures Helpers
          • Cursor Helper
          • Exec Helper
          • Functional Equivalence Helpers
          • Into Helper
      • Teradata to JavaScript Translation Reference
        • GET DIAGNOSTICS EXCEPTION
        • Macros
        • Procedures
      • Teradata to Snowflake Scripting Translation Reference
        • ABORT and ROLLBACK
        • BEGIN END
        • CASE
        • CREATE MACRO
        • CREATE PROCEDURE
        • CURSOR
        • DECLARE
        • DECLARE CONDITION HANDLER
        • DML and DDL Objects
        • EXCEPTION HANDLERS
        • EXECUTE IMMEDIATE
        • EXECUTE/EXEC
        • FUNCTION OPTIONS OR DATA ACCESS
        • GET DIAGNOSTICS EXCEPTION
        • IF
        • LOCKING FOR ACCESS
        • LOOP
        • OUTPUT PARAMETERS
        • PREPARE
        • REPEAT
        • SET
        • SYSTEM_DEFINED
        • WHILE
    • Oracle
      • Sample data
      • Basic Elements of Oracle SQL
        • Data Types
          • Oracle Built-in Data Types
            • Character Data Types
              • CHAR Data type
              • NCHAR Data Type
              • VARCHAR2 Data Type
              • VARCHAR Data Type
              • NVARCHAR2 Data Type
            • Numeric Data Types
              • NUMBER Data Type
              • FLOAT Data Type
              • Floating-Point Numbers
                • BINARY_FLOAT
                • BINARY_DOUBLE
            • LONG Data Type
            • Datetime and Interval Data Types
              • DATE Data Type
              • TIMESTAMP Data Type
              • TIMESTAMP WITH TIME ZONE Data Type
              • TIMESTAMP WITH LOCAL TIME ZONE Data Type
              • INTERVAL YEAR TO MONTH Data Type
              • INTERVAL DAY TO SECOND Data Type
              • Datetime Arithmetic
                • Interval UDFs vs Snowflake native interval operation
            • LOB Data Types
              • BFILE Data Type
              • BLOB Data Type
              • CLOB Data Type
              • NCLOB Data type
            • JSON Data Type
            • Extended Data Types
            • RAW and LONG RAW Data types
            • PL SQL Data Types
              • PLS_INTEGER Data Type
              • BINARY_INTEGER Data Type
          • Rowid Data Type
            • ROWID DataType
            • UROWID Data Type
          • ANSI Data Types
          • User-Defined Types
            • REF Data Types
          • Any Types
            • ANYTYPE
            • ANYDATA
            • ANYDATASET
          • XML Types
            • XMLType
            • URI Data Types
              • HTTPURIType
              • XDBURIType
              • DBURIType
            • URIFactory Package
          • Spatial Types
            • SDO_GEOMETRY
            • SDO_TOPO_GEOMETRY
            • SDO_GEORASTER
        • Literals
          • Interval Literal
          • Interval Type and Date Type
          • Text literals
      • Pseudocolumns
        • ROWID
        • ROWNUM
      • Built-in functions
        • SnowConvert Custom UDFs
          • BFILENAME UDF
          • DATE_TO_JULIANDAYS_UDF
          • DATEADD UDF
          • DATEDIFF UDF
          • INTERVAL UDFs
            • DATEADD UDF INTERVAL
            • DATEDIFF UDF INTERVAL
          • CAST_DATE UDF
          • JSON_VALUE UDF
          • JULIAN TO GREGORIAN DATE UDF
          • MONTHS BETWEEN UDF [DEPRECATED]
          • REGEXP LIKE UDF
          • TIMESTAMP DIFF UDF
          • TRUNC (date) UDF
          • TRUNC (number) UDF
        • TO_NUMBER
        • NLSSORT
      • Built-In packages
        • DBMS_LOB
          • SUBSTR Function
        • DBMS_RANDOM
          • VALUE functions
        • DBMS_OUTPUT
          • PUT_LINE procedure
        • UTL_FILE
          • FOPEN procedure
          • PUT_LINE procedure
          • FCLOSE procedure
      • SQL Queries and Subqueries
        • Select
          • Select Flashback Query
        • Joins
          • Equijoin
          • Band Join
          • Self Join
          • Cartesian Products
          • Inner Join
          • Outer Join
          • Antijoin
          • Semijoin
      • SQL Statements
        • Alter Session
        • Alter Table
        • Create Materialized Views
        • Create Database Link
        • Create Index
        • Create Sequence
        • Create Synonym
        • Create Table
        • Create Type
          • Object Type Definition
          • Subtype Definition
          • Array Type Definition
          • Nested Table Type Definition
          • Member Function Definitions
        • Create View
        • Drop Table
      • PL/SQL to Snowflake Scripting
        • ASSIGNMENT STATEMENT
        • CALL
        • CASE
        • COLLECTIONS AND RECORDS
          • Associative Array Type Definition
          • Varray Type Definition
          • Nested Table Array Type Definition
          • Collection Methods
          • Collection Bulk Operations
            • WITH, SELECT, and BULK COLLECT INTO statements
          • Record Type Definition
        • COMPOUND STATEMENTS
        • CONTINUE
        • CREATE PROCEDURE
        • CURSOR
          • PARAMETRIZED CURSOR
          • CURSOR DECLARATION
          • Workaround for cursors using parameters or procedure variables
          • Cursor Variables
        • DECLARE
        • DEFAULT PARAMETERS
        • DML STATEMENTS
          • INSERT Statement Extension
          • MERGE Statement
          • SELECT INTO Statement
          • Work around to simulate the use of Records
        • EXIT
        • EXPRESSIONS
        • EXECUTE IMMEDIATE
        • FORALL
        • FOR LOOP
        • HELPERS
          • Bulk Cursor Helpers
        • IF
        • IS EMPTY
        • LOCK TABLE
        • LOG ERROR
        • LOOP
        • OUTPUT PARAMETERS
        • PACKAGES
          • DECLARATION
          • BODY
          • VARIABLES
          • Constants
        • PROCEDURE CALL
        • RAISE
        • RAISE_APPICATION_ERROR
        • UDF CALL
        • WHILE
      • PL/SQL to Javascript
        • Procedures
        • User defined functions
        • Packages
        • Helpers
          • EXEC Helper
          • Cursor Helper
          • Raise Helper
          • ROWTYPE Helper
          • Between operator helper
          • Like operator Helper
          • IS NULL Helper
          • Concat Value Helper
          • Package variables helper
          • Implicit Cursor attribute helper
        • Declarations
        • Control Statements
        • Conditional Compilation
        • Collections & Records
        • DDL - DML Statements
        • SQL Language Elements
        • Expressions and operators
        • Synonyms
        • Triggers
        • TYPE attribute
      • SQL*Plus
        • Archive Log
        • Attribute
        • Break
        • Btitle
        • Change
        • Column
        • Define
        • Host
        • Prompt
        • Remark
        • Set
        • Spool
        • Start
        • Whenever oserror
        • Whenever sqlerror
        • Show
        • Append
        • Accept
      • Wrapped objects
    • SQLServer
      • General Language Elements
        • COMPUTED COLUMN
        • EXECUTE
          • System Store Procedures
            • SP_RENAME
        • Collate
        • USE
        • OUTER APPLY
      • DDLs
        • Tables
        • Index
        • Views
        • Procedures
        • Functions
      • DMLs
        • Set Operators
        • Between
        • Update
        • Select
        • Insert
        • Delete
        • Merge
        • Exists
        • IN
        • Truncate
        • Drop
        • Bulk Insert
        • Common Table Expression (CTE)
        • Drops
      • Data Types
      • Statements
        • ALTER
          • TABLE
            • ADD
              • COLUMN DEFINITION
                • COLUMN CONSTRAINT
                  • FOREIGN KEY
                  • PRIMARY KEY / UNIQUE
                  • CHECK
              • TABLE CONSTRAINT
                • FOREIGN KEY
                • PRIMARY KEY
                • CHECK CONSTRAINT
                • CHECK
                • CONNECTION
                • DEFAULT
                • ON PARTITION
        • CREATE
          • FUNCTION
            • SCALAR
            • INLINE TABLE-VALUED
            • MULTI-STATEMENT TABLE-VALUED
      • Built-in functions
        • SnowConvert custom UDFs
          • OPENXML UDF
          • STR UDF
          • SWITCHOFFSET_UDF
        • Aggregate functions
          • COUNT
          • COUNT_BIG
          • SUM
        • Analytic Functions
          • LAG
        • Conversion functions
          • CONVERT
          • TRY_CONVERT
        • Data Type functions
          • DATALENGTH
        • Date & Time functions
          • AT TIME ZONE
          • SWITCHOFFSET
          • DATEADD
          • DATEDIFF
          • DATEPART
          • DATEFROMPARTS
          • DATENAME
          • DAY
          • EOMONTH
          • GETDATE
          • MONTH
          • SYSDATETIME
          • SYSUTCDATETIME
          • YEAR
        • Logical functions
          • IIF
        • Mathematical functions
          • ABS
          • ACOS
            • ACOS in JS
          • ASIN
            • ASIN in JS
          • ATAN
            • ATAN in JS
          • ATN2
            • ATAN2 in JS
          • AVG
          • CEILING
          • COS
            • COS in JS
          • COT
            • COT in JS
          • DEGREES
            • DEGREES in JS
          • EXP
            • EXP in JS
          • FLOOR
          • LOG
            • LOG in JS
          • LOG10
            • LOG10 in JS
          • PI
            • PI in JS
          • POWER
            • POW in JS
          • SQUARE
          • STDEV
          • STDEVP
          • VAR
          • POWER
          • RADIANS
            • RADIANS in JS
          • ROUND
          • SQRT
        • Metadata functions
          • DB_NAME
          • OBJECT_ID
        • Ranking functions
          • DENSE_RANK
          • RANK
          • ROW_NUMBER
        • String functions
          • ASCII
            • ASCII in JS
          • CHAR
          • CHARINDEX
          • COALESCE
          • CONCAT
          • CONCAT_WS
            • Join in JS
          • DIFFERENCE
            • DIFFERENCE in JS
          • FORMAT
            • FORMAT in JS
          • LEFT
          • LEN
          • LOWER
          • LTRIM
            • LTRIM in JS
          • NCHAR
          • PATINDEX
            • search in JS
          • QUOTENAME
            • QUOTENAME in JS
          • REPLACE
          • REPLICATE
          • REVERSE
            • reverse in JS
          • RIGHT
          • RTRIM
          • SOUNDEX
            • SOUNDEX in JS
          • SPACE
          • STR
            • STR in JS
          • STRING_ESCAPE
            • stringify in JS
          • SUBSTRING
          • TRIM
            • trim in JS
          • UPPER
        • System functions
          • FORMATMESSAGE
            • FORMATMESSAGE_UDF
          • ISNULL
          • NEWID
          • NULLIF
        • XML Functions
          • Value
          • Query
      • Built-in procedures
        • Custom User Defined Procedures
          • SP_ADDEXTENDEDPROPERTY_UDP
      • Snowflake Scripting
        • CREATE PROCEDURE
        • CASE
        • CURSOR
        • DECLARE
        • EXECUTE
        • IF
        • SET
        • DMLs
        • CALL
        • WHILE
        • DROPs
        • BEGIN and COMMIT Transaction
        • OUTPUT PARAMETERS
        • LABEL and GOTO
        • SELECT
        • TEXTIMAGE_ON
        • TRY CATCH
      • System Tables
        • SYS.FOREIGN_KEYS
      • Queries
        • TOP
Powered by GitBook
On this page
  • Description
  • Current SnowConvert Support
  • Sample Source Patterns
  • COUNT
  • EXISTS
  • FIRST/LAST
  • DELETE
  • EXTEND
  • TRIM
  • LIMIT
  • PRIOR/NEXT
  • Known Issues
  • Related EWIs
  1. Translation Reference
  2. Oracle
  3. PL/SQL to Snowflake Scripting
  4. COLLECTIONS AND RECORDS

Collection Methods

This is a translation reference to convert the Oracle Collection Methods to Snowflake

PreviousNested Table Array Type DefinitionNextCollection Bulk Operations

Last updated 1 year ago

This section is a work in progress, information may change in the future

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.

()

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

Not Recognized.

Not Translated.

UDF

Not Recognized.

Not Translated.

UDF (To be defined)

Not Recognized.

Not Translated.

UDF

Not Recognized.

Not Translated.

Not Recognized.

Not Translated.

UDF

Not Recognized.

Not Translated.

UDF

Not Recognized.

Not Translated.

Not Recognized.

Not Translated.

Not Supported.

Not Recognized.

Not Translated.

UDF (To be defined)

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

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

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'.

In Oracle, using this operation on Nested Tables causes it to have "undefined" elements within it due to them being sparse.

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 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 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.

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.

The snowflake equivalent is the method.

The snowflake equivalent is the method. Note that, when using Varchar elements, casting to Variant is necessary.

This functionality may be implemented using

Oracle PL/SQL Language Reference COLLECTION METHODS
ARRAY_SIZE
ARRAY_CONTAINS
ARRAY_SLICE
ARRAY_CONTAINS
ARRAY_SIZE
DELETE
TRIM
EXTEND
EXISTS
FIRST
LAST
COUNT
LIMIT
PRIOR
NEXT