PL/SQL List to Struct
This post shows you how to take a list of strings and convert them into a struct(ure) of a date, number, and string. Oracle implements IDL (Interface Description Language), which means the solution requires creating:
- An attribute data type (ADT), or collection of a standard date type, which in this case is a varchar2 (variable length string).
- A user defined type (UDT), which is an object type with or without methods. In this case, it implements a UDT without methods.
- A collection of the UDT object type (known in Oracle’s parlance as a table).
Here’s the data definition language (DDL) for the three required structures:
- The ADT of strings:
CREATE OR REPLACE TYPE tre IS TABLE OF VARCHAR2(100); /
- The UDT struct(ure) object type:
CREATE OR REPLACE TYPE struct IS OBJECT ( xdate DATE , xnumber NUMBER , xstring VARCHAR2(20)); /
- The UDT structs collection or Oracle table:
CREATE OR REPLACE TYPE structs IS TABLE OF struct; /
Next, we create a function that accepts a collection of strings and returns a record UDT, which is the struct(ure) object type. As PL/SQL code gets larger, using conditional compilation can help discover problems.
Enable conditional compilation with the following statement:
ALTER SESSION SET PLSQL_CCFLAGS = 'debug:1'; |
The cast_strings function is defined as:
CREATE OR REPLACE FUNCTION cast_strings ( pv_list TRE ) RETURN struct IS /* Declare a UDT and initialize an empty struct variable. */ lv_retval STRUCT := struct( xdate => NULL , xnumber => NULL , xstring => NULL); /* A debugger function. */ FUNCTION debugger ( pv_string VARCHAR2 ) RETURN VARCHAR2 IS /* Declare return value. */ lv_retval VARCHAR2(60); BEGIN /* Conditional compilation evaluation. */ $IF $$DEBUG = 1 $THEN lv_retval := 'Evaluating ['||pv_string||']'; $END /* Return debug value. */ RETURN lv_retval; END debugger; BEGIN /* Loop through list of values to find only the numbers. */ FOR i IN 1..pv_list.LAST LOOP /* Print debugger remark. */ dbms_output.put_line(debugger(pv_list(i))); /* Ensure that a sparsely populated list can't fail. */ IF pv_list.EXISTS(i) THEN /* Order if number evaluation before string evaluation. */ CASE /* Implement WHEN clause that checks that the xnumber member is null and that the pv_list element contains only digits; and assign the pv_list element to the lv_retval's xnumber member. */ WHEN REGEXP_LIKE(pv_list(i),'^[[:digit:]]*$') THEN lv_retval.xnumber := pv_list(i); /* Implement WHEN clause that checks that the xdate member is null and that the pv_list element is a valid date; and assign the pv_list element to the lv_retval's xdate member. */ WHEN verify_date(pv_list(i)) THEN lv_retval.xdate := pv_list(i); /* Implement WHEN clause that checks that the xstring member is null and that the pv_list element contains only alphanumeric values; and assign the pv_list element to the lv_retval's xstring member. */ WHEN REGEXP_LIKE(pv_list(i),'^([[:alnum:]]|[[:punct:]]|[[:space:]])*$') THEN lv_retval.xstring := pv_list(i); ELSE NULL; END CASE; END IF; END LOOP; /* Print the results. */ RETURN lv_retval; END; / |
The following tests the cast_strings function:
DECLARE /* Define a list. */ lv_list TRE := tre('16-APR-2018','Day after ...','1040'); /* Declare a structure. */ lv_struct STRUCT := struct( xdate => NULL , xnumber => NULL , xstring => NULL); BEGIN /* Assign a parsed value set to get a value structure. */ lv_struct := cast_strings(lv_list); /* Print the values of the compound struct variable. */ dbms_output.put_line('xstring ['||lv_struct.xstring||']'); dbms_output.put_line('xdate ['||TO_CHAR(lv_struct.xdate,'DD-MON-YYYY')||']'); dbms_output.put_line('xnumber ['||lv_struct.xnumber||']'); END; / |
If the PLSQL_CCFLAGS is enabled for the session, the function will display these three rows:
Evaluating [16-APR-2018] Evaluating [DAY after ...] Evaluating [1040] |
Whether the PLSQL_CCFLAGS is set or not, the test case returns the following:
xstring [DAY after ...] xdate [16-APR-2018] xnumber [1040] |
As always, I hope this helps those looking for new approaches.