Discussions
Categories
- 385.5K All Categories
- 5.1K Data
- 2.5K Big Data Appliance
- 2.5K Data Science
- 453.4K Databases
- 223.2K General Database Discussions
- 3.8K Java and JavaScript in the Database
- 47 Multilingual Engine
- 606 MySQL Community Space
- 486 NoSQL Database
- 7.9K Oracle Database Express Edition (XE)
- 3.2K ORDS, SODA & JSON in the Database
- 585 SQLcl
- 4K SQL Developer Data Modeler
- 188K SQL & PL/SQL
- 21.5K SQL Developer
- 46 Data Integration
- 46 GoldenGate
- 298.4K Development
- 4 Application Development
- 20 Developer Projects
- 166 Programming Languages
- 295K Development Tools
- 150 DevOps
- 3.1K QA/Testing
- 646.7K Java
- 37 Java Learning Subscription
- 37.1K Database Connectivity
- 201 Java Community Process
- 108 Java 25
- 22.2K Java APIs
- 138.3K Java Development Tools
- 165.4K Java EE (Java Enterprise Edition)
- 22 Java Essentials
- 176 Java 8 Questions
- 86K Java Programming
- 82 Java Puzzle Ball
- 65.1K New To Java
- 1.7K Training / Learning / Certification
- 13.8K Java HotSpot Virtual Machine
- 94.3K Java SE
- 13.8K Java Security
- 208 Java User Groups
- 25 JavaScript - Nashorn
- Programs
- 667 LiveLabs
- 41 Workshops
- 10.3K Software
- 6.7K Berkeley DB Family
- 3.6K JHeadstart
- 6K Other Languages
- 2.3K Chinese
- 207 Deutsche Oracle Community
- 1.1K Español
- 1.9K Japanese
- 474 Portuguese
What is the alternative for 'for loop' ?

i want to update the table by using a decrementor and row id as below.
my_line_count := 0;
select count(*) into my_line_count from emp where empno = in_empno
For line_rec in ( select rowid from emp where empno = in_empno order by countline desc)
loop
update emp set countline = my_line_count where ROWID = line_rec.ROWID;
my_line_count = my_line_count -1;
end loop;
This procedure will be called for suppose 314 times, by another procedure( based on count in emp table i:e for each row);
Before data is like
select countline from emp where empno = in_empno ;
countline
1
1
1
1
1
-- so on
Expected result
select countline from emp where empno = in_empno ; (For exapmle there are 314 rows)
countline
314
313
312
311
.
.
.
3
2
1
Is there any way to perform above logic without loop?
Answers
-
Please provide some example data and the expected results of the logic you want so we can understand better what you are trying to do.
At first sight it looks like you want to just do a MERGE statement to update data based on some determined values, and that would be better than a query followed by a row by row loop, as it would keep everything as a single transaction and avoid conflict with other sessions that may (in your case) update the data inbetween you querying and updating each row.
Without data though, it's hard to determine exactly what you're trying to do.
-
I have added more details now to the question. Here we are updating values using a decrementor. hence we are using loop. So if we have more rows like in millions, the iterations will be more , hence i want to avoid this loop for performance issues. But to update row by row without loop , is this possible?
-
I think you are trying to re-number the "countline" values for an employee in sequential order. Something like this perhaps...
SQL> create table myemp as 2 select 1 as empno, 2 as countline from dual union all 3 select 1, 4 from dual union all 4 select 1, 7 from dual union all 5 select 1, 9 from dual union all 6 select 2, 1 from dual union all 7 select 2, 2 from dual union all 8 select 2, 8 from dual 9 / Table created. SQL> -- counting the records for an emp and then assigning the line count-1 SQL> -- in descending order from the last countline is the same as SQL> -- just re-numbering all the countlines in ascending order from 1 upwards SQL> merge into myemp t 2 using (select rowid as rid 3 ,empno 4 ,row_number() over (partition by empno order by countline) as new_countline 5 from myemp 6 ) s 7 on (t.rowid = s.rid) 8 when matched then 9 update set countline = s.new_countline 10 / 7 rows merged. SQL> select * 2 from myemp 3 / EMPNO COUNTLINE ---------- ---------- 1 1 1 2 1 3 1 4 2 1 2 2 2 3 7 rows selected.
In this case, I've re-numbered for all the employee records, but you could limit that to a known employee number if you want.
-
Thank you , i will try with this logic and see if i get the expected result.
-
I have tried this with my data set but it took total 102 minutes to process. Previously when 'for loop' was used it took 72 minutes only. Looks like merge statement is taking more time to process than for loop. Is there any other way to improve performance?
-
Processing data in a single SQL statement, with MERGE should typically be a lot faster than row-by-row updates using multiple SQL Updates that switch between the PL engine and the SQL engine.
You haven't shown what you've tried and we don't have your actual data.
Are you doing the merge across all the data in one go, or are you calling it for each of the employee numbers one after the other?
Are there other people using the data? i.e. sessions that could be causing (b)locks on it?
How much data is there? What indexes does it have?
As a simple comparison, a difference in timing between using a merge and row-by-row updates...
SQL> drop table myemp purge 2 / Table dropped. SQL> create table myemp as 2 -- select 1 as empno, 2 as countline from dual union all 3 -- select 1, 4 from dual union all 4 -- select 1, 7 from dual union all 5 -- select 1, 9 from dual union all 6 -- select 2, 1 from dual union all 7 -- select 2, 2 from dual union all 8 -- select 2, 8 from dual 9 -- generate larger set of data for timing comparison 10 -- 1,000 employees with 25 lines each = 25,000 rows 11 with empno as (select level as empno from dual connect by level <= 1000) -- 10,000 employees 12 ,lns as (select 1 as countline from dual connect by level <= 25) -- 250 lines per employee 13 select empno 14 ,countline 15 from empno 16 cross join lns 17 / Table created. SQL> create index imyemp on myemp(empno, countline) 2 / Index created. SQL> -- counting the records for an emp and then assigning the line count-1 SQL> -- in descending order from the last countline is the same as SQL> -- just re-numbering all the countlines in ascending order from 1 upwards SQL> set timing on; SQL> merge into myemp t 2 using (select rowid as rid 3 ,empno 4 ,row_number() over (partition by empno order by countline) as new_countline 5 from myemp 6 ) s 7 on (t.rowid = s.rid) 8 when matched then 9 update set countline = s.new_countline 10 / 25000 rows merged. Elapsed: 00:00:03.47 SQL> set timing off; SQL> select * 2 from myemp 3 where rownum <= 20 -- just sample 4 / EMPNO COUNTLINE ---------- ---------- 1 1 1 2 1 3 1 4 1 5 1 6 1 7 1 8 1 9 1 10 1 11 1 12 1 13 1 14 1 15 1 16 1 17 1 18 1 19 1 20 20 rows selected. SQL> commit; Commit complete. SQL> drop table myemp purge 2 / Table dropped. SQL> create table myemp as 2 with empno as (select level as empno from dual connect by level <= 1000) -- 10,000 employees 3 ,lns as (select 1 as countline from dual connect by level <= 25) -- 250 lines per employee 4 select empno 5 ,countline 6 from empno 7 cross join lns 8 / Table created. SQL> create index imyemp on myemp(empno, countline) 2 / Index created. SQL> set timing on; SQL> declare 2 en number := -1; 3 c number; 4 cursor cemp is 5 select * 6 from myemp 7 order by empno, countline 8 for update; 9 begin 10 for e in cemp 11 loop 12 if en != e.empno then 13 en := e.empno; 14 c := 1; 15 else 16 c := c+1; 17 end if; 18 update myemp 19 set countline = c 20 where current of cemp; 21 end loop; 22 end; 23 / PL/SQL procedure successfully completed. Elapsed: 00:00:08.93 SQL> set timing off; SQL> select * 2 from myemp 3 where rownum <= 20 4 / EMPNO COUNTLINE ---------- ---------- 1 1 1 2 1 3 1 4 1 5 1 6 1 7 1 8 1 9 1 10 1 11 1 12 1 13 1 14 1 15 1 16 1 17 1 18 1 19 1 20 20 rows selected. SQL> commit; Commit complete.
So the row by row processing took more than twice as long as the merge (around 8.9 seconds compared to the merge's 3.4 seconds); and my row-by-row processing is probably more efficient than your version as I'm not doing a count of records for each employee, I'm just setting a counter to 1 at the start of each employee number and incrementing that to update the current row of the cursor loop.
This is why you need to show us exactly what you're doing, especially when you make claims that a single MERGE statement is slower than multiple update statements in a loop.
-
SQL> select a from (select level a from dual connect by level <= &emp_no) order by a desc;
Enter value for emp_no: 12
old 1: select a from (select level a from dual connect by level <= &emp_no) order by a desc
new 1: select a from (select level a from dual connect by level <= 12) order by a desc
A
----------
12
11
10
9
8
7
6
5
4
3
2
1
12 rows selected.
-
What on Earth is that supposed to achieve? That is nothing like the requirement. It just generates as many rows as the employee id number which is completely unrelated to the rows the employee has on the table.
😲
-
@BluShadow Thank you so much good sir, using your merge solution I was able to reduce my JOB execution time dramatically. From couple hours to mere mins.