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.