Home » RDBMS Server » Performance Tuning » Simple Query on Table with Billions of rows getting ORA-01652 (Oracle Database 19c Enterprise Edition Release 19.0.0.0.0)
Simple Query on Table with Billions of rows getting ORA-01652 [message #690044] Wed, 25 September 2024 13:27 Go to next message
wtolentino
Messages: 421
Registered: March 2005
Senior Member
A simple query on a table with billions of rows is getting an error:

ORA-01652: unable to extend temp segment by 128 in tablespace TEMP

TEMP tablespace has 3 datafile and each has a maxsize of 32003mb. Currently no other session is active or is connected to the same database.


This query completes without error:
select count(*) cnt from TRANSACTION_tab;
Please advise thank you.



This query throws an error ORA-01652:
select * from TRANSACTION_tab describe trans_dt desc;
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690045 is a reply to message #690044] Wed, 25 September 2024 13:54 Go to previous messageGo to next message
John Watson
Messages: 8962
Registered: January 2010
Location: Global Village
Senior Member
Your count(*) query can probably run by scanning an index. THe select * query will have to look at the table. It is the usual thing we all (should) know: get the execution plans to see what is happening.
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690046 is a reply to message #690044] Wed, 25 September 2024 14:00 Go to previous messageGo to next message
Michel Cadot
Messages: 68728
Registered: March 2007
Location: Saint-Maur, France, https...
Senior Member
Account Moderator

COUNT(*) just requires to count rows one by one, no need of (temp) space.

SELECT * ... ORDER BY ... requires to store all rows (or index values and rowid) in temp space to then sort them.

As John said, see the execution plans to know what is done.

Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690047 is a reply to message #690046] Wed, 25 September 2024 21:01 Go to previous messageGo to next message
wtolentino
Messages: 421
Registered: March 2005
Senior Member
here's the explain plan.

explain plan for select count(*) cnt from TRANSACTION_tab;
Plan hash value: 3371900491
 
------------------------------------------------------------------------------------------
| Id  | Operation             | Name                     | Rows  | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |                          |     1 |  1479K  (1)| 00:00:58 |
|   1 |  SORT AGGREGATE       |                          |     1 |            |          |
|   2 |   INDEX FAST FULL SCAN| TRANSACTION_TAB_PK       |  1290M|  1479K  (1)| 00:00:58 |
------------------------------------------------------------------------------------------

explain plan for select * from TRANSACTION_tab order by trans_dt desc;
Plan hash value: 2017279614
 
----------------------------------------------------------------------------------------------------
| Id  | Operation          | Name                  | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |                       |  1290M|   103G|       |    39M  (1)| 00:25:34 |
|   1 |  SORT ORDER BY     |                       |  1290M|   103G|   161G|    39M  (1)| 00:25:34 |
|   2 |   TABLE ACCESS FULL| TRANSACTION_TAB       |  1290M|   103G|       |  4562K  (1)| 00:02:59 |
----------------------------------------------------------------------------------------------------
note: not the actual table name
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690048 is a reply to message #690047] Thu, 26 September 2024 00:47 Go to previous messageGo to next message
Michel Cadot
Messages: 68728
Registered: March 2007
Location: Saint-Maur, France, https...
Senior Member
Account Moderator

So you have your answer.

Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690049 is a reply to message #690048] Thu, 26 September 2024 06:36 Go to previous messageGo to next message
cookiemonster
Messages: 13961
Registered: September 2008
Location: Rainy Manchester
Senior Member
To ask the obvious question - what is the point of ordering 1.29 billion rows?
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690050 is a reply to message #690049] Thu, 26 September 2024 07:59 Go to previous messageGo to next message
wtolentino
Messages: 421
Registered: March 2005
Senior Member
The order by is to get the latest rows.
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690051 is a reply to message #690050] Thu, 26 September 2024 09:05 Go to previous messageGo to next message
Michel Cadot
Messages: 68728
Registered: March 2007
Location: Saint-Maur, France, https...
Senior Member
Account Moderator

If you want only some rows have a look at row limiting clause (after ORDER BY one), for instance:
FETCH FIRST 100 ROWS ONLY

Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690052 is a reply to message #690050] Thu, 26 September 2024 09:12 Go to previous messageGo to next message
cookiemonster
Messages: 13961
Registered: September 2008
Location: Rainy Manchester
Senior Member
if you want the latest rows why are getting all the rows?

If there's an index on trans_dt then oracle can process
select * from (select * from TRANSACTION_tab order by trans_dt desc) 
where rownum < [whatever]
really fast, because it can ignore most of the data in the table.
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690069 is a reply to message #690052] Wed, 02 October 2024 08:23 Go to previous messageGo to next message
wtolentino
Messages: 421
Registered: March 2005
Senior Member
Right I can use FETCH FIRST 100 ROWS ONLY or rownum < ....

It just because I'm used to do select * from table order by .... to write the query quick.
Re: Simple Query on Table with Billions of rows getting ORA-01652 [message #690070 is a reply to message #690069] Wed, 02 October 2024 10:24 Go to previous message
cookiemonster
Messages: 13961
Registered: September 2008
Location: Rainy Manchester
Senior Member
quick and dirty selects are fine on dev systems with limited data, but when you've got a system with billions of rows you need to think about the implications of every single query you write.
Previous Topic: Parallel Degree Limit correct num to use on Parallel Hints
Next Topic: Performances and tuning
Goto Forum:
  


Current Time: Sat Dec 21 09:55:30 CST 2024