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
Memory problem in spring framework

In SPRING framework, a delete query causes an UncategorizedSQLException and an ORACLE memory problem.
I'm attempting to run a delete query in eclipse using the SPRING jdbcTemplate and ORACLE as the database. The code is as follows:
jdbcTemplate.update("DELETE FROM PRMSVC_EF WHERE EF_SSC_ID in (SELECT es.EF_SSC_ID FROM EF_SSC es WHERE es.NUMCPTPFS = '1086878547'")
I receive an error
org.springframework.jdbc.UncategorizedSQLException : StatementCallback; uncategorized SQLException for [DELETE FROM PRMSVC_EF WHERE EF_SSC_ID in (SELECT es.EF_SSC_ID FROM EF_SSC es WHERE es.NUMCPTPFS = '1086878547']
as well as the following Oracle error:
ORA-12853 : ORA-12853: insufficient memory for PX buffers
When I run the query in Oracle DBMS, it takes 2 seconds to complete. Rather than trying to extend the SGA pools memory or something, I was looking for a solution for the java code itself when I stumbled upon this article with a detailed flow chart for query optimization. Any suggestions?
Best Answer
-
ORA-12853 : ORA-12853: insufficient memory for PX buffers
This indicates that your query is using parallel processing. The first thing to check is the DOP (Degree Of Parallelism) you are using. You should not be using a very large DOP because it might cause a massive transfer of rows between two parallel server sets particularly when the distribution method is PX BROADCAST. The PX servers store their generated data in TQ tables. Those temporary TQ tables are stored in the large pool portion of the SGA. When this large pool is full you hit the above error.
So, check the execution plan of your delete query and get the DOP. Since there is no parallel hint in your query it is fairly likely that the parallelism is coming from your tables/indexes that are decorated with a degree !='1'. You can check this using the following queries
select table_name, degree from all_tables where owner ='C##MHOURI' and trim(degree) !='1'; select index_name, table_name, degree from all_indexes where owner ='C##MHOURI' and trim(degree) !='1'; INDEX_NAME TABLE_NAME DEGREE -------------------- -------------------- ---------------------------------------- T1_IDX T1 4
Best regards
Mohamed Houri
Answers
-
ORA-12853 : ORA-12853: insufficient memory for PX buffers
This indicates that your query is using parallel processing. The first thing to check is the DOP (Degree Of Parallelism) you are using. You should not be using a very large DOP because it might cause a massive transfer of rows between two parallel server sets particularly when the distribution method is PX BROADCAST. The PX servers store their generated data in TQ tables. Those temporary TQ tables are stored in the large pool portion of the SGA. When this large pool is full you hit the above error.
So, check the execution plan of your delete query and get the DOP. Since there is no parallel hint in your query it is fairly likely that the parallelism is coming from your tables/indexes that are decorated with a degree !='1'. You can check this using the following queries
select table_name, degree from all_tables where owner ='C##MHOURI' and trim(degree) !='1'; select index_name, table_name, degree from all_indexes where owner ='C##MHOURI' and trim(degree) !='1'; INDEX_NAME TABLE_NAME DEGREE -------------------- -------------------- ---------------------------------------- T1_IDX T1 4
Best regards
Mohamed Houri