This site is currently read-only as we are migrating to Oracle Forums for an improved community experience. You will not be able to initiate activity until January 30th, when you will be able to use this site as normal.

    Forum Stats

  • 3,889,900 Users
  • 2,269,775 Discussions
  • 7,916,823 Comments

Discussions

Memory problem in spring framework

User_SQDZD
User_SQDZD Member Posts: 11 Green Ribbon

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?

Tagged:

Best Answer

  • Mohamed Houri
    Mohamed Houri Member Posts: 1,310 Bronze Trophy
    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

    Jonathan Lewis

Answers

  • Mohamed Houri
    Mohamed Houri Member Posts: 1,310 Bronze Trophy
    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

    Jonathan Lewis