Failed to reserve contiguous memory

  • Thats the article reference I was looking for! I believe it only relates to variables or constants in WHERE clauses of SQL statements. If they aren't 'DECLARED' SQL server assumes they are variant and allocates 8K of contiguous memory to each one. It's what I was trying to explain in my first post.

    I have checked your code and I don't think the article applies in your case.

    The only other thing I am not sure about is if the parameters for the procedure get put into contiguous memory. If they are, you could see if changing them to 8000K varchars (if practical) affects your problem.

    Peter

  • Hello!

    Varchar(8000) is not large enough to store XML documents I use.

    Instead of it, I decided to remove the XML document handle after each use. I wish it will help to free more rapidly the memory for other users...

    Next step (if the problem occurs again) would be using temporary tables with indexes (like Peter said), and call Microsoft SQL Support.

    (Until I wait for the network team to remove the 3GB option... )

    Here is the new version of my store Proc :

    -----------

    --------------------------------------------------------------------------------

    CREATE PROCEDURE           PARITOP_SAVECDRESULTATMASSE

    /*****************************************************************************************************************/

    /* Objectif :  Enregistrement des résultats du cacul de masse de façon atomique    */

    /* Date        Auteur   Modification       */

    /* ----------  ---------------  ------------------------------------------------------------------------ */

    /* 2003-04-29  Anne-Marie Guay Création initiale      */

    /* 2004-07-20 Anne-Marie Guay suppression des documents XML apres chaque utilisation  */

    /*****************************************************************************************************************/

     @PRC_ID INT,

     @MONDE TINYINT,

     @DATA_COMPARABLE TEXT,

     @DATA_RESULTAT TEXT,

     @DATA_RESIDUEL TEXT,

     @DATA_CDBAREME TEXT,

     @DATA_CDBAREMEFORF TEXT,

     @DATA_VARAJUSTCOMP TEXT,

     @DATA_VARAJUSTCOMPFORF TEXT

    )

    AS

    DECLARE @hDoc_Comparable int

    DECLARE @hDoc_Resultat int

    DECLARE @hDoc_CDBareme int

    DECLARE @hDoc_CDBaremeForf int

    DECLARE @hDoc_Residuel int

    DECLARE @hDoc_VarAjustComp int

    DECLARE @hDoc_VarAjustCompForf int

    exec sp_xml_preparedocument @hDoc_Comparable OUTPUT,@DATA_COMPARABLE, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    exec sp_xml_preparedocument @hDoc_Resultat OUTPUT,@DATA_RESULTAT, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    exec sp_xml_preparedocument @hDoc_CDBareme OUTPUT,@DATA_CDBAREME, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    exec sp_xml_preparedocument @hDoc_CDBaremeForf OUTPUT,@DATA_CDBAREMEFORF, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    exec sp_xml_preparedocument @hDoc_Residuel OUTPUT,@DATA_RESIDUEL, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    exec sp_xml_preparedocument @hDoc_VarAjustComp OUTPUT,@DATA_VARAJUSTCOMP, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    exec sp_xml_preparedocument @hDoc_VarAjustCompForf OUTPUT,@DATA_VARAJUSTCOMPFORF, '<root xmlns:rs="urn:schemas-microsoft-com:rowset" xmlns:z="#RowsetSchema"/>'

    BEGIN TRAN SAVERESULT

     ---Dans tous les cas, on supprime le résultat du monde de l,analyse

     --Soit pour faire un ménage, ou soit pour permettre de faire une insertion d'un résultat du monde de l'analyse, sans collision de clés.

     UPDATE PARITOP_RESULTAT

     SET RST_A_SUPPRIMER = 1

     FROM PARITOP_RESULTAT RST INNER JOIN

      OPENXML (@hDoc_Resultat,'xml/rs:data/z:row',0)

      WITH (  PRC_ID INT,

        UE_ID INT,

        RST_MONDE TINYINT

     &nbsp A  ON A.UE_ID = RST.UE_ID AND A.PRC_ID =RST.PRC_ID AND A.RST_MONDE = RST.RST_MONDE

     WHERE RST.RST_MONDE = 0 -- Monde de l'analyse

     

     

     --iNSERTION DES RÉSULTATS ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_RESULTAT( 

          PRC_ID,

          UE_ID,

          RST_MONDE,

          RST_PARITE,

          RST_PARITEMIN,

          RST_PARITEMAX,

          RST_INDICEVRAISS,

          RST_NIVCONCORDANCE,

          RST_ENVAJUST,

          RST_DATECALCUL,

          RST_STATUTCALCUL,

          RST_A_SUPPRIMER,

          RST_ELIG_NB_VENTES,

          RST_ELIG_VAL_MOY_ROLE,

          RST_ELIG_PV_MOYEN,

          RST_ELIG_RATIO_DISPERS,

          RST_ELIG_IND_SEL_MIN,

          RST_ELIG_IND_SEL_MAX,

          RST_ELIG_IND_SEL_MOY

         &nbsp

     SELECT  PRC_ID,

       UE_ID,

       RST_MONDE,

       RST_PARITE,

       RST_PARITEMIN,

       RST_PARITEMAX,

       RST_INDICEVRAISS,

       RST_NIVCONCORDANCE,

       RST_ENVAJUST,

       RST_DATECALCUL,

       RST_STATUTCALCUL,

       0,

       RST_ELIG_NB_VENTES,

       RST_ELIG_VAL_MOY_ROLE,

       RST_ELIG_PV_MOYEN,

       RST_ELIG_RATIO_DISPERS,

       RST_ELIG_IND_SEL_MIN,

       RST_ELIG_IND_SEL_MAX,

       RST_ELIG_IND_SEL_MOY

     FROM OPENXML (@hDoc_Resultat,'xml/rs:data/z:row',0)

     WITH (  PRC_ID INT,

       UE_ID INT,

       RST_MONDE TINYINT,

       RST_PARITE FLOAT,

       RST_PARITEMIN FLOAT,

       RST_PARITEMAX FLOAT,

       RST_INDICEVRAISS FLOAT,

       RST_NIVCONCORDANCE FLOAT,

       RST_ENVAJUST FLOAT,

       RST_DATECALCUL SMALLDATETIME,

       RST_STATUTCALCUL TINYINT,

       RST_ELIG_NB_VENTES INT,

       RST_ELIG_VAL_MOY_ROLE FLOAT,

       RST_ELIG_PV_MOYEN FLOAT,

       RST_ELIG_RATIO_DISPERS FLOAT,

       RST_ELIG_IND_SEL_MIN FLOAT,

       RST_ELIG_IND_SEL_MAX FLOAT,

       RST_ELIG_IND_SEL_MOY FLOAT

    &nbsp

     

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DU RESULTAT

      EXEC sp_xml_removedocument @hDoc_Resultat

      GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DU RESULTAT

     EXEC sp_xml_removedocument @hDoc_Resultat

     

     --iNSERTION DES BAREMES ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_CD_BAREME( 

           VAR_ID,

           CDB_BAREME,

           CDB_BAREMEMIN,

           CDB_BAREMEMAX,

           RST_ID

          &nbsp

     SELECT  

       VAR_ID,

       CDB_BAREME,

       CDB_BAREMEMIN,

       CDB_BAREMEMAX,

       (SELECT  Top 1 RST_ID FROM PARITOP_RESULTAT RST WHERE RST.PRC_ID = A.PRC_ID AND RST.UE_ID = A.UE_ID AND RST.RST_MONDE = A.RST_MONDE AND RST_A_SUPPRIMER = 0)

     FROM OPENXML (@hDoc_CDBareme,'xml/rs:data/z:row',0)

     WITH (  

       PRC_ID INT,

       UE_ID INT,

       RST_MONDE TINYINT,

       VAR_ID INT,

       CDB_BAREME FLOAT,

       CDB_BAREMEMIN FLOAT,

       CDB_BAREMEMAX FLOAT

     &nbsp A

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DES BAREMES

      EXEC sp_xml_removedocument @hDoc_CDBareme

       GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DES BAREMES

     EXEC sp_xml_removedocument @hDoc_CDBareme

     --INSERTION DES BAREMES FORFAITAIRES ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_CD_BAREMEFORF( 

           

           VAF_ID,

           CBF_BAREME,

           CBF_BAREMEMIN,

           CBF_BAREMEMAX,

           RST_ID

        &nbsp

     SELECT  

       VAF_ID,

       CBF_BAREME,

       CBF_BAREMEMIN,

       CBF_BAREMEMAX,

          (SELECT  Top 1 RST_ID FROM PARITOP_RESULTAT RST WHERE RST.PRC_ID = A.PRC_ID AND RST.UE_ID = A.UE_ID AND RST.RST_MONDE = A.RST_MONDE AND RST_A_SUPPRIMER = 0)

     FROM OPENXML (@hDoc_CDBaremeForf,'xml/rs:data/z:row',0)

     WITH (  

       PRC_ID INT,

       UE_ID INT,

       RST_MONDE TINYINT,

       VAF_ID INT,

       CBF_BAREME FLOAT,

       CBF_BAREMEMIN FLOAT,

       CBF_BAREMEMAX FLOAT

     &nbsp A

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DES BAREMES FORFAITAIRES

      EXEC sp_xml_removedocument @hDoc_CDBaremeForf

      GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DES BAREMES FORFAITAIRES

     EXEC sp_xml_removedocument @hDoc_CDBaremeForf

     

     --INSERTION DES COMPARABLES ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_COMPARABLE( 

          

          VEN_ID,

          CMP_SELMAN,

          CMP_INDICESELECTION,

          CMP_PVRES,

          CMP_UTILISE,

          CMP_PVAJUSTE,

          CMP_PVRHAB,

          CMP_TVM,

          RST_ID

       &nbsp

     SELECT  

       

       VEN_ID,

       CASE  CMP_SELMAN

        WHEN 'False' THEN 0

        WHEN 'True' THEN 1

       END,

       CMP_INDICESELECTION,

       CMP_PVRES,

       CASE CMP_UTILISE

        WHEN 'False' THEN 0

        WHEN 'True' THEN 1

       END,

       CMP_PVAJUSTE,

       CMP_PVRHAB,

       CMP_TVM,

       (SELECT  Top 1 RST_ID FROM PARITOP_RESULTAT RST WHERE RST.PRC_ID = A.PRC_ID AND RST.UE_ID = A.UE_ID AND RST.RST_MONDE = A.RST_MONDE AND RST_A_SUPPRIMER = 0)

     FROM OPENXML (@hDoc_Comparable,'xml/rs:data/z:row',0)

     WITH (PRC_ID INT,UE_ID INT,VEN_ID INT,RST_MONDE TINYINT,CMP_SELMAN VARCHAR(10),CMP_INDICESELECTION FLOAT,CMP_PVRES FLOAT,CMP_UTILISE VARCHAR(10),CMP_PVAJUSTE FLOAT ,CMP_PVRHAB FLOAT, CMP_TVM FLOAT) A

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DES COMPARABLES

      EXEC sp_xml_removedocument @hDoc_Comparable

      GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DES COMPARABLES

     EXEC sp_xml_removedocument @hDoc_Comparable

     

     --INSERTION DES AJUSTEMENTS DES COMPARABLES------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_VARAJUSTCOMP(      

          VAR_ID,

          VEN_ID,

          VJC_AJUST,

          VJC_AJUSTMIN,

          VJC_AJUSTMAX,

          RST_ID

       &nbsp

     SELECT  

       VAR_ID,

       VEN_ID,

       VJC_AJUST,

       VJC_AJUSTMIN,

       VJC_AJUSTMAX,

       (SELECT  Top 1 RST_ID FROM PARITOP_RESULTAT RST WHERE RST.PRC_ID = A.PRC_ID AND RST.UE_ID = A.UE_ID AND RST.RST_MONDE = A.RST_MONDE AND RST_A_SUPPRIMER = 0)

     FROM OPENXML (@hDoc_VarAjustComp,'xml/rs:data/z:row',0)

     WITH (  

       PRC_ID INT,

       VAR_ID INT,

       UE_ID INT,

       VEN_ID INT,

       RST_MONDE TINYINT,

       VJC_AJUST FLOAT,

       VJC_AJUSTMIN FLOAT,

       VJC_AJUSTMAX FLOAT

     &nbsp A

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DES AJUSTEMENTS DES COMPARABLES

      EXEC sp_xml_removedocument @hDoc_VarAjustComp

      GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DES AJUSTEMENTS DES COMPARABLES

     EXEC sp_xml_removedocument @hDoc_VarAjustComp

     --INSERTION DES AJUSTEMENTS FORFAITAIRES DES COMPARABLES------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_VARAJUSTCOMPFORF( 

          VAF_ID,

          VEN_ID,

          VFC_AJUST,

          VFC_AJUSTMIN,

          VFC_AJUSTMAX,

          RST_ID

       &nbsp

     SELECT  

       VAF_ID,

       VEN_ID,

       VFC_AJUST,

       VFC_AJUSTMIN,

       VFC_AJUSTMAX,

       (SELECT  Top 1 RST_ID FROM PARITOP_RESULTAT RST WHERE RST.PRC_ID = A.PRC_ID AND RST.UE_ID = A.UE_ID AND RST.RST_MONDE = A.RST_MONDE AND RST_A_SUPPRIMER = 0)

     FROM OPENXML (@hDoc_VarAjustCompForf,'xml/rs:data/z:row',0) 

     WITH (  

       PRC_ID INT,

       VAF_ID INT,

       UE_ID INT,

       VEN_ID INT,

       RST_MONDE TINYINT,

       VFC_AJUST FLOAT,

       VFC_AJUSTMIN FLOAT,

       VFC_AJUSTMAX FLOAT

     &nbsp A

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DES AJUSTEMENTS FORFAITAIRES DES COMPARABLES

      EXEC sp_xml_removedocument @hDoc_VarAjustCompForf

      GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DES AJUSTEMENTS FORFAITAIRES DES COMPARABLES

     EXEC sp_xml_removedocument @hDoc_VarAjustCompForf

     

     

     --iNSERTION DU RESIDUEL--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

     INSERT INTO PARITOP_RESIDUEL( 

          VAR_ID,

          VEN_ID,

          RES_PV,

          RES_ENVAJUST_1,

          RES_ENVAJUST_2,

          RES_FACTEUR_1,

          RES_FACTEUR_2,

          RES_PVRHABILLE,

          RST_ID

       &nbsp

     SELECT  

       VAR_ID,

       VEN_ID,

       RES_PV,

       RES_ENVAJUST_1,

       RES_ENVAJUST_2,

       RES_FACTEUR_1,

       RES_FACTEUR_2,

       RES_PVRHABILLE,

       (SELECT  Top 1 RST_ID FROM PARITOP_RESULTAT RST WHERE RST.PRC_ID = A.PRC_ID AND RST.UE_ID = A.UE_ID AND RST.RST_MONDE = A.RST_MONDE AND RST_A_SUPPRIMER = 0)

     FROM OPENXML (@hDoc_Residuel,'xml/rs:data/z:row',0)

     WITH (PRC_ID INT,VAR_ID INT,UE_ID INT,VEN_ID INT,RST_MONDE TINYINT,RES_PV FLOAT,RES_ENVAJUST_1 FLOAT,RES_ENVAJUST_2 FLOAT,RES_FACTEUR_1 FLOAT,RES_FACTEUR_2 FLOAT,RES_PVRHABILLE FLOAT) A

     IF @@ERROR <> 0

     BEGIN

      --SUPPRESSION DU XML DES RÉSIDUELS

      EXEC sp_xml_removedocument @hDoc_Residuel

      GOTO TRAITER_ERR

     END

     --SUPPRESSION DU XML DES RÉSIDUELS

     EXEC sp_xml_removedocument @hDoc_Residuel 

    COMMIT TRAN  SAVERESULT

    CLEANUP:

     RETURN

    TRAITER_ERR:

     ROLLBACK TRAN SAVERESULT

     GOTO CLEANUP

    GO

    -----------

  • Hi Anne,

    I found this on the Microsoft web site, although we get a State of 14 but have also had State of 17.

    Hope it helps

    Colin

    FIX: JDBC Driver Leaks Server Cursors

    Applies To

    SYMPTOMS

    The Microsoft SQL Server 2000 Driver for JDBC does not close server cursors that it opens under some conditions. This can cause cursor build up and memory pressure on Microsoft SQL Server. This can also cause server and application performance degradation, so that eventually clients can no longer connect to the SQL Server.

    The following errors may be reported in the SQL Server error log:

    2003-05-06 11:24:10.82 server Error: 17803, Severity: 20, State: 17

    2003-05-06 11:24:10.82 server Insufficient memory available.

    2003-05-06 11:25:26.94 spid395 BPool::Map: no remappable address found.

    Microsoft SQL Server may return the following error message to the client, but this message is generally not reported in the SQL Server error log:

    Error 701: There is insufficient system memory to run this query.

    The driver leaks the server cursor when all the following conditions are true:

    • The connection is opened with SelectMethod = Cursor property set.
    • The statement is executed with the execute method.
    • No resultset is retrieved.
    • The statement is closed.

    CAUSE

    According to the JDBC specifications, when a statement is closed, the driver immediately releases the database of the object of that statement, and also releases the JDBC resources. However, because of a bug in the Microsoft SQL Server 2000 Driver for JDBC, when a statement is executed with the execute method, the driver only closes retrieved resultsets. This behavior implicitly closes the associated server cursor. If no resultset is retrieved, the server cursor is left open.

    RESOLUTION

    A supported hotfix is now available from Microsoft, but it is only intended to correct the problem that is described in this article. Only apply it to systems that are experiencing this specific problem. This hotfix may receive additional testing. Therefore, if you are not severely affected by this problem, Microsoft recommends that you wait for the next service pack that contains this hotfix.

    To resolve this problem immediately, contact Microsoft Product Support Services to obtain the hotfix. For a complete list of Microsoft Product Support Services phone numbers and information about support costs, visit the following Microsoft Web site:

    http://support.microsoft.com/default.aspx?scid=fh;%5BLN%5D;CNTACTMS

    Note In special cases, charges that are ordinarily incurred for support calls may be canceled if a Microsoft Support Professional determines that a specific update will resolve your problem. The usual support costs will apply to additional support questions and issues that do not qualify for the specific update in question.

    The English version of this fix has the file attributes (or later) that are listed in the following table. The dates and times for these files are listed in coordinated universal time (UTC). When you view the file information, it is converted to local time. To find the difference between UTC and local time, use the Time Zone tab in the Date and Time tool in Control Panel.

    The Windows version of this fix has the following properties:   Date         Time   Version            Size    File name   --------------------------------------------------------------   05-May-2003  17:27  2.2.0034          286,788  Msbase.jar   05-May-2003  17:27  2.2.0034           67,159  Mssqlserver.jar   05-May-2003  17:27  2.2.0034           58,903  Msutil.jarThe Unix-based version of this fix has the following properties:   Date         Time   Version            Size    File name   --------------------------------------------------------------   05-May-2003  14:27  2.2.0034          286,788  Msbase.jar   05-May-2003  14:27  2.2.0034           67,159  Mssqlserver.jar   05-May-2003  14:27  2.2.0034           58,903  Msutil.jar

    Note Although the file timestamp may be different for each operating system that is listed, internally the files are exactly the same. The best way to determine the version of the driver that you are using is to use the getDriverVersion method of the DatabaseMetaData interface.

    WORKAROUND

    To work around this problem use one of the following methods.

    Note If your application uses any third-party components that may execute queries under the covers with the conditions that are mentioned in the "Symptoms" section of this article, use only the first method. Only the first method might work around the problem when you use these third-party components.

    • Method 1: Use the default SelectMethod. When the SelectMethod = Cursor Connection property is not set, the driver always uses the SelectMethod = Direct option. The SelectMethod = Direct does not open any cursors on the server.
    • Method 2: Use the executeQuery method instead of the execute method on the statement.
    • Method 3: Return the resultset by using the getResultSet method on the statement after you execute the query. In this case, the Close method on the statement implicitly closes the resultset and the associated server cursor.

    STATUS

    Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.

    MORE INFORMATION

    You can use Performance Monitor to monitor the number of cursors that are opened in Microsoft SQL Server. To do this, use the SQL Server:Cache Manager performance object, and then select the Cache Object Counts counter and the Cursors instance. If this counter shows a steady increase in value up to the point of the out of memory condition, you might be experiencing the problem that is mentioned in the "Symptoms" section of this article.

    Steps to Reproduce the Problem

    1. Start SQL Profiler to trace the calls to the SQL Server that the application connects to. Make sure that the trace properties are set to include the Stored Procedures event. Start the trace.
    2. Compile, and then run the following Java code.

      Note You must replace the server name, the user id, and the password in the connection string as appropriate for your environment.

      import java.sql.*;import java.io.*;import java.lang.Object.*;public class CursorLeak{ public static void main( String args[] ){ Connection conn = null; Statement stmt = null; ResultSet result = null; try{ Class.forName("com.microsoft.jdbc.sqlserver.SQLServerDriver");conn=DriverManager.getConnection("jdbc:microsoft:sqlserver://myServer:1433;DatabaseName=myDatabase;SelectMethod=Cursor;User=UserID;Password=password" );      //Workaround #1: Use SelectMethod = Direct      //conn=DriverManager.getConnection("jdbc:microsoft:sqlserver://myServer:1433;DatabaseName=myDatabase;SelectMethod=Direct;User=UserID;Password=password" );}catch( Exception e ){ System.out.println( e ); } try{ stmt = conn.createStatement(); String query = "Select CompanyName, City, Phone from Customers"; stmt.execute( query );             //Workaround #2: If you call executeQuery() instead of execute(), stmt.close() closes the cursor.      //ResultSet rs = stmt.executeQuery( query );      //Workaround #3: If you call getResultset() after you call execute(), stmt.close() closes the cursor.      //ResultSet rs = stmt.getResultSet();         //Closing explicitly the ResultSet closes the cursor      //if(stmt != null)      //rs.close();System.out.println( "Close" );       stmt.close();try  {System.out.println("Wait");Thread.sleep(10000);}catch(Exception e){System.out.println(e.getMessage());}  }catch( SQLException e ){ System.out.println( e ); }}}

    3. Check the Profiler output. You see sp_cursoropen and sp_cursorfetch. However, but the sp_cursorclose call is not there.

     

Viewing 3 posts - 16 through 17 (of 17 total)

You must be logged in to reply to this topic. Login to reply