This discussion is archived
2 Replies Latest reply: Feb 8, 2013 1:34 PM by rp0428 RSS

SOLVED: How can I use or call a function that returns %ROWTYPE?

9423755 Explorer
Currently Being Moderated
Hi
edit: you can probably skip all this guff and go straight to the bottom...In the end this is probably just a question of how to use a function that returns a %rowtype.  Thanks.




Currently reading Feuerstein's tome, 5th ed. I've downloaded and run the file genaa.sp, which is a code generator. Specifically, you feed it a table name and it generates code (package header and package body) that will create a cache of the specified table's contents.
So, I ran:
HR@XE> @"C:\Documents and Settings\Jason\My Documents\Work\SQL\OPP5.WEB.CODE\OPP5.WEB.CODE\genaa.sp"
749  /

Procedure created.

HR@XE> exec genaa('EMPLOYEES');
which generated a nice bunch of code, viz:
create or replace package EMPLOYEES_cache is
    function onerow ( EMPLOYEE_ID_in IN HR.EMPLOYEES.EMPLOYEE_ID%TYPE) return HR.EMPLOYEES%ROWTYPE;
    function onerow_by_EMP_EMAIL_UK (EMAIL_in IN HR.EMPLOYEES.EMAIL%TYPE) return HR.EMPLOYEES%ROWTYPE;
    procedure test;
end EMPLOYEES_cache;
/
create or replace package body EMPLOYEES_cache is
    TYPE EMPLOYEES_aat IS TABLE OF HR.EMPLOYEES%ROWTYPE INDEX BY PLS_INTEGER;
    EMP_EMP_ID_PK_aa EMPLOYEES_aat;
    TYPE EMP_EMAIL_UK_aat IS TABLE OF HR.EMPLOYEES.EMPLOYEE_ID%TYPE INDEX BY HR.EMPLOYEES.EMAIL%TYPE;
    EMP_EMAIL_UK_aa EMP_EMAIL_UK_aat;
    function onerow ( EMPLOYEE_ID_in IN HR.EMPLOYEES.EMPLOYEE_ID%TYPE) 
        return HR.EMPLOYEES%ROWTYPE is 
        begin 
            return EMP_EMP_ID_PK_aa (EMPLOYEE_ID_in); 
        end;
    function onerow_by_EMP_EMAIL_UK (EMAIL_in IN HR.EMPLOYEES.EMAIL%TYPE) 
        return HR.EMPLOYEES%ROWTYPE is 
        begin 
            return EMP_EMP_ID_PK_aa (EMP_EMAIL_UK_aa (EMAIL_in)); 
        end;
    procedure load_arrays is 
        begin
            FOR rec IN (SELECT * FROM HR.EMPLOYEES)
            LOOP
                EMP_EMP_ID_PK_aa(rec.EMPLOYEE_ID) := rec;
                EMP_EMAIL_UK_aa(rec.EMAIL) := rec.EMPLOYEE_ID;
            end loop;
        END load_arrays;
    procedure test is
        pky_rec HR.EMPLOYEES%ROWTYPE;
        EMP_EMAIL_UK_aa_rec HR.EMPLOYEES%ROWTYPE;
        begin
            for rec in (select * from HR.EMPLOYEES) loop
                pky_rec := onerow (rec.EMPLOYEE_ID);
                EMP_EMAIL_UK_aa_rec := onerow_by_EMP_EMAIL_UK (rec.EMAIL);
                if rec.EMPLOYEE_ID = EMP_EMAIL_UK_aa_rec.EMPLOYEE_ID then
                    dbms_output.put_line ('EMP_EMAIL_UK  lookup OK');
                else
                    dbms_output.put_line ('EMP_EMAIL_UK  lookup NOT OK');
                end if;
            end loop;
        end test;
    BEGIN 
        load_arrays;
    end EMPLOYEES_cache;
/
which I have run successfully:
HR@XE> @"C:\Documents and Settings\Jason\My Documents\Work\SQL\EMPLOYEES_CACHE.sql"

Package created.


Package body created.
I am now trying to use the functionality within the package.

I have figured out that the section
    BEGIN 
        load_arrays;
    end EMPLOYEES_cache;
/
is the initialization section, and my understanding is that this is supposed to run when any of the package variables or functions are referenced. Is that correct?
With that in mind, I'm trying to call the onerow() function, but it's not working:
HR@XE> select onerow(100) from dual;
select onerow(100) from dual
       *
ERROR at line 1:
ORA-00904: "ONEROW": invalid identifier


HR@XE> select employees_cache.onerow(100) from dual;
select employees_cache.onerow(100) from dual
       *
ERROR at line 1:
ORA-06553: PLS-801: internal error [55018]


HR@XE> select table(employees_cache.onerow(100)) from dual;
select table(employees_cache.onerow(100)) from dual
       *
ERROR at line 1:
ORA-00936: missing expression
He provides the code genaa.sp, and a very brief description of what it does, but doesn't tell us how to run the generated code!
Now, I have just done some googling, and it seems that what I am trying to do isn't possible. Apparently %ROWTYPE is PL/SQL, and not understood by SQL, so you can't call onerow() from sql. Correct?
So I try wrapping the call in an exec:
HR@XE> exec select employees_cache.onerow(100) from dual;
BEGIN select employees_cache.onerow(100) from dual; END;

                             *
ERROR at line 1:
ORA-06550: line 1, column 30:
PLS-00382: expression is of wrong type
ORA-06550: line 1, column 7:
PLS-00428: an INTO clause is expected in this SELECT statement


HR@XE> exec select table(employees_cache.onerow(100)) from dual;
BEGIN select table(employees_cache.onerow(100)) from dual; END;

             *
ERROR at line 1:
ORA-06550: line 1, column 14:
PL/SQL: ORA-00936: missing expression
ORA-06550: line 1, column 7:
PL/SQL: SQL Statement ignored


HR@XE> exec employees_cache.onerow(100)
BEGIN employees_cache.onerow(100); END;

      *
ERROR at line 1:
ORA-06550: line 1, column 7:
PLS-00221: 'ONEROW' is not a procedure or is undefined
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored
No joy.

Of course, now that I'm looking at it again, it seems that the way to go is indicated by the first error:
PLS-00428: an INTO clause is expected in this SELECT statement
So am I supposed to create a type of EMPLOYEES%ROWTYPE in a PL/SQL procedure, and the idea of this code, is that the first call to onerow() runs the initialiation code, which populates the cache, and all subsequent calls to onerow() (whether by my session or any other) will use the cache?

I've had a stab at this, but still, no joy:
create or replace procedure testcache is
    emp employees%rowtype;
    begin
        select employees_cache.onerow(100) from dual into emp;
        dbms_output.put_line('Emp id: ' || emp.employee_id);
    end testcache;
/
show errors

HR@XE> @testcache.sql

Warning: Procedure created with compilation errors.

Errors for PROCEDURE TESTCACHE:

LINE/COL ERROR
-------- -----------------------------------------------------------------
4/9      PL/SQL: SQL Statement ignored
4/54     PL/SQL: ORA-00933: SQL command not properly ended
HR@XE>
Have a feeling this should be really easy. Can anybody help?
Many thanks in advance.
Jason

Edited by: 942375 on 08-Feb-2013 11:45
  • 1. SOLVED: Re: How can I use or call a function that returns %ROWTYPE?
    9423755 Explorer
    Currently Being Moderated
    Ha, figured it out (the answer was on the next page, duh!).
    create or replace procedure testcache is
        emp employees%rowtype;
        begin
            emp :=  employees_cache.onerow(100);
            dbms_output.put_line('Emp id: ' || emp.employee_id);
        end testcache;
    /
    show errors
    
    HR@XE> @testcache.sql
    
    Procedure created.
    
    No errors.
    HR@XE> exec testcache
    Emp id: 100
    
    PL/SQL procedure successfully completed.
    
    HR@XE>
  • 2. Re: SOLVED: Re: How can I use or call a function that returns %ROWTYPE?
    rp0428 Guru
    Currently Being Moderated
    >
    Ha, figured it out
    >
    Hopefully you also figured out that the example is just that: a technical example of how to use certain Oracle functionality. Unfortunately it is also an example of what you should NOT do in an actual application.

    That code isn't scaleable, uses expensive PGA memory, has no limit on the amount of memory that might be used and, contrary to your belief will result in EVERY SESSION HAVING ITS OWN CACHE of exactly the same data if the session even touches that package.

    Mr. Feuerstein is an expert in SQL and PL/SQL and his books cover virtually all of the functionality available. He also does an excellent job of providing examples to illustrate how that functionality can be combined and used. But the bulk of those examples are intended solely to illustrate the 'technical' aspects of the technology. They do not necessarily reflect best practices and they often do not address performance or other issues that need to be considered when actually using those techniques in a particular application. The examples show WHAT can be done but not necessarily WHEN or even IF a given technique should be used.

    It is up to the reader to learn the advantages and disadvantages of each technicalogical piece and determine when and how to use them.
    >
    Now, I have just done some googling, and it seems that what I am trying to do isn't possible. Apparently %ROWTYPE is PL/SQL, and not understood by SQL, so you can't call onerow() from sql. Correct?
    >
    That is correct. To be used by SQL you would need to create SQL types using the CREATE TYPE syntax. Currently that syntax does not support anything similar to %ROWTYPE.
    >
    So am I supposed to create a type of EMPLOYEES%ROWTYPE in a PL/SQL procedure, and the idea of this code, is that the first call to onerow() runs the initialiation code, which populates the cache, and all subsequent calls to onerow() (whether by my session or any other) will use the cache?
    >
    NO! That is a common misconception. Each session has its own set of package variables. Any session that touches that package will cause the entire EMPLOYEES table to be queried and stored in a new associative array specifically for that session.

    That duplicates the cache for each session using the package. So while there might be some marginal benefit for a single session to cache data like that the benefit usually disappears if multiple sessions are involved.

    The main use case that I am aware of where such caching has benefit is during ETL processing of staged data when the processing of each record is too complex to be done in SQL and the records need to be BULK loaded and the data manipulated in a loop. Then using an associative array as a lookup table to quickly get a small amount of data can be effective. And if the ETL procedure is being processed in parallel (meaning different sessions) then for a small lookup array the additional memory use is tolerable.

    Mitigating against that is the fact that:

    1. Such frequently used data that you might store in the array is likely to be cached by Oracle in the buffer cache anyway
    2. Newer versions of Oracle now have more than one cache
    3. The SQL query needed to get the data from the table will use a bind variable that eliminates repeated hard parsing.
    4. The cursor and the buffer caches ARE SHARED by multiple sessions globally.

    So the short story is that there would rarely be a use case where ARRAYs like that would be preferred over accessing the data from the table.

Legend

  • Correct Answers - 10 points
  • Helpful Answers - 5 points