What process is consuming my VAS Reservation

  • I am encountering an error on one of our environments where further logins are not allowed anymore. Only way to resolve the problem is to restart the SQLServer Instance.

    Different SQL Memory Changes were done on the instance from Enabling/Disabling AWE, changing min and max memory to adding -g to the startup option.

    Environment is 32bit, SQL Server 2005 SP3. Memory on the server is 4GB.

    After reading several articles, I started monitoring the VAS reservation. I used the query stated on this link http://sqlblogcasts.com/blogs/christian/archive/2008/01/07/sql-server-memtoleave-vas-and-64-bit.aspx

    Currently AWE is enabled on the instance with max memory of 2.4GB. The -g512 was added to the startup parameter. However, it only prolonged the error being encountered. Usually, the error occurs(further logins not allowed) when Max Free Size goes down to 2MB.

    From what I read, the resources/processes that is using the VAS are the ff:

    1) Any OLE/COM components loaded in SQL Server

    2) Extended Stored Procedures

    3) SQL Mail components

    4) Any prepared documents using sp_xml_preparedocument

    5) Linked Server Providers

    6) Large Plans stored in Procedure Cache

    7) Very frequent Backups also may cause MTL area depletion.

    8) SQL CLR

    Are there any DMVs I could check to pinpoint which of these components is consuming the VAS? Or are there procedures to troubleshoot the problem?

    Any suggestions, links and ideas are welcome 🙂

    Thanks In advance

  • From Understanding the VAS Reservation (aka MemToLeave) in SQL Server by Jonathan Kehayias this shows you the clerks using VAS in detail:

    SELECT type, virtual_memory_committed_kb, multi_pages_kb

    FROM sys.dm_os_memory_clerks

    WHERE virtual_memory_committed_kb > 0 OR multi_pages_kb > 0

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • Thanks for the reply.

    Did run the query and got the these result:

    typevirtual_memory_committed_kbmulti_pages_kb

    MEMORYCLERK_SQLBUFFERPOOL68481144

    OBJECTSTORE_LOCK_MANAGER40960

    MEMORYCLERK_SQLSTORENG115256

    MEMORYCLERK_SQLUTILITIES2400

    MEMORYCLERK_SOSNODE06072

    MEMORYCLERK_SOSNODE02800

    MEMORYCLERK_SQLGENERAL02456

    CACHESTORE_SQLCP0344

    MEMORYCLERK_SQLSERVICEBROKER0192

    CACHESTORE_OBJCP0112

    MEMORYCLERK_SQLOPTIMIZER088

    MEMORYCLERK_HOST064

    MEMORYCLERK_SNI016

    MEMORYCLERK_SNI016

    CACHESTORE_STACKFRAMES08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    CACHESTORE_STACKFRAMES08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    OBJECTSTORE_SNI_PACKET08

    From the information gathered, how could I actually pinpoint which processes is consuming VAS. Which clerks actually relates to dblinks, CLR, etc.

    Thanks in advance.

  • Nothing is really standing out as holding onto a large amount of virtual memory at the moment. You can also have this issue if the VAS becomes fragmented and there no way to defragment it short of rebooting. What are you using to do backups? Are you running any third-party products or extended stored procedures on the server?

    The best move really would be to move onto a 64-bit platform.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • Thanks again for the reply...

    We don't have 3rd Party backup software as we are using Maintenance Plans for our backup. As with extended stored procedures also. Will have to verify this one. Is there any view to check if this is actually being used?

    What we have are DBLinks to SQL server, Oracle and DB2 databases. I am suspecting this is eating up the VAS.

  • sqlserverdba1316 (1/20/2013)


    Thanks again for the reply...

    We don't have 3rd Party backup software as we are using Maintenance Plans for our backup. As with extended stored procedures also. Will have to verify this one. Is there any view to check if this is actually being used?

    USE master;

    SELECT * FROM sys.extended_procedures;

    What we have are DBLinks to SQL server, Oracle and DB2 databases. I am suspecting this is eating up the VAS.

    Use of Linked Servers can easily be the cause of something like what you're seeing. I have dealt with the problem you are seeing on 32-bit SQL 2005 SP4 and it was traced to a combination of third-party extended stored procedures (XSP) that were part of the backup software being used and Linked Server usage. I could show that after reboot an initial select from one of the Linked Servers on the instance (to a MySQL instance) would drop the largest VAS chunk avaialble significantly. To mitigate the issue the server was rebooted weekly every weekend. The final resolution was to upgrade to a 64-bit version of SQL Server.

    edit: fix quote tags

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

Viewing 6 posts - 1 through 5 (of 5 total)

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