Skip to Main Content
  • Questions
  • UPDATE command on nested tables(PL/SQL objects)

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Suresh.

Asked: September 26, 2008 - 4:50 pm UTC

Last updated: September 29, 2008 - 9:30 am UTC

Version: 10.1

Viewed 1000+ times

You Asked

Hello Tom,

How to update nested table(PL/SQL object) using UPDATE command?

CREATE OR REPLACE TYPE test_obj AS OBJECT(e_id NUMBER
,e_name VARCHAR2(10),e_sal NUMBER);
/
CREATE OR REPLACE TYPE test_obj_tab AS TABLE OF test_obj;
/

DECLARE
l_test_obj_tab test_obj_tab := test_obj_tab(test_obj(1,'A',10)
,test_obj(1,'B',20)
,test_obj(1,'C',30));
BEGIN
--display by casting
FOR vrec IN(SELECT * FROM TABLE(CAST(l_test_obj_tab AS test_obj_tab)))
LOOP
dbms_output.put_line(vrec.e_id||' '||vrec.e_name||' '||vrec.e_sal);
END LOOP;
--update attributes by using index
FOR l_index IN l_test_obj_tab.FIRST..l_test_obj_tab.LAST
LOOP
l_test_obj_tab(l_index).e_sal := l_test_obj_tab(l_index).e_sal*10;
END LOOP;
--update by casting, how????
/*UPDATE TABLE(CAST(l_test_obj_tab AS test_obj_tab))
SET e_sal = e_sal*20; */
END;

Thanks in Advance
~Suresh

and Tom said...

You cannot perform modification DML on a collection variable.

You can select the modified data into a new collection.


ops$tkyte%ORA10GR2> DECLARE
  2  l_test_obj_tab test_obj_tab := test_obj_tab(test_obj(1,'A',10)
  3                                ,test_obj(1,'B',20)
  4                                ,test_obj(1,'C',30));
  5  l_modified test_obj_tab;
  6  BEGIN
  7      select test_obj(e_id,e_name,e_sal*1.10)
  8        bulk collect into l_modified
  9        from table(l_test_obj_tab);
 10
 11      for i in 1 .. l_modified.count
 12      loop
 13          dbms_output.put_line
 14          ( 'old('||i||') = test_obj(' ||
 15             l_test_obj_tab(i).e_id || ', ' ||
 16             l_test_obj_tab(i).e_name || ', ' ||
 17             l_test_obj_tab(i).e_sal ||
 18             ') new('||i||') = ' ||
 19             l_modified(i).e_id || ', ' ||
 20             l_modified(i).e_name || ', ' ||
 21             l_modified(i).e_sal );
 22      end loop;
 23  end;
 24  /
old(1) = test_obj(1, A, 10) new(1) = 1, A, 11
old(2) = test_obj(1, B, 20) new(2) = 1, B, 22
old(3) = test_obj(1, C, 30) new(3) = 1, C, 33

PL/SQL procedure successfully completed.


Is this answer out of date? If it is, please let us know via a Comment

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library