What is using the RAM?

  • Hi everyone, I've been investigating RAM bottleneck on one of my servers, and it looks like the buffer pool is only using 23GB out of 51GB for buffer pool, but I am unable to find out what is using the remaining 28GB of RAM.  I've run some queries and am attaching the results for your consideration.  This server has SQL 2012 Enterprise (SP3) on Windows 2012 Standard.  Thanks in advance!

  • shahgols - Tuesday, December 19, 2017 2:51 PM

    Hi everyone, I've been investigating RAM bottleneck on one of my servers, and it looks like the buffer pool is only using 23GB out of 51GB for buffer pool, but I am unable to find out what is using the remaining 28GB of RAM.  I've run some queries and am attaching the results for your consideration.  This server has SQL 2012 Enterprise (SP3) on Windows 2012 Standard.  Thanks in advance!

    When you query sys.dm_os_memory_clerks, look at the other memory clerk types - the ones that are not MEMORYCLERK_SQLBUFFERPOOL.
    I don't know of a list of all of the different types -  usually just search on the types.
    You can find some additional queries for troubleshooting memory issues in this post:
    Troubleshooting SQL Server Memory

    Sue

  • This was removed by the editor as SPAM

  • Hi Sue, I have done a SUM on pages_kb in dm_os_memory_clerks, which adds up the space taken by all clerk types.  The total is 22GB.  SQL Server is using 51GB, and PLE is 51, so that's why I am wondering where the rest of the RAM has gone.

    Hi Subramanian, do you have any scripts, there is a lot of information in those tables and I am not sure what I am looking for.

  • shahgols - Thursday, December 21, 2017 8:59 AM

    Hi Sue, I have done a SUM on pages_kb in dm_os_memory_clerks, which adds up the space taken by all clerk types.  The total is 22GB.  SQL Server is using 51GB, and PLE is 51, so that's why I am wondering where the rest of the RAM has gone.

    Hi Subramanian, do you have any scripts, there is a lot of information in those tables and I am not sure what I am looking for.

    There are over 20 different queries in the link I provided that will walk you through your memory usage - it would likely be good to read the article and work through the scripts. They are all memory specific - the link is: 
    Troubleshooting SQL Server Memory

    In addition to the memory clerks, his advise is to also use the following - refer to the article for more information:
    select * from sys.dm_os_memory_objects
    select * from sys.dm_os_memory_pools
    select * from sys.dm_os_memory_nodes
    select * from sys.dm_os_memory_cache_entries
    select * from sys.dm_os_memory_cache_hash_tables

    Sue

  • This was removed by the editor as SPAM

  • Hi Sue, thanks for the response.  I had actually been to that very page and been through all the scripts.  I am still unable to find an answer.

  • I assuming here that you're talking about the 'page buffer cache'. This cache contains recently read pages,which are periodically cycled out using an algorithm based on frequency of usage. The cache pages aren't tied the query or process that read them, but each page can be identified by object type and object name.

    The following query will provide detailed information about page buffer cache allocation.


    -- Object level allocation for each database:
    IF OBJECT_ID('tempdb..#BufferCacheAllocation') IS NOT NULL
        DROP TABLE #BufferCacheAllocation;
    GO
    CREATE TABLE #BufferCacheAllocation
    (
        Database_Name VARCHAR(200) NOT NULL,
        Object_Name VARCHAR(200) NULL,
        Page_Type VARCHAR(30) NULL,
        Index_Name VARCHAR(200) NULL,
        Index_Type VARCHAR(30) NULL,
        Data_Compression_Desc VARCHAR(20) NULL,
        Row_Count BIGINT NULL,
        BufferAllocated_MB BIGINT NULL,
        BufferWaste_MB BIGINT NULL
    );
    exec sp_MsForEachDB
    '
    USE ?;
    INSERT INTO #BufferCacheAllocation
    (
        Database_Name,
        Object_Name,
        Page_Type,
        Index_Name,
        Index_Type,
        Data_Compression_Desc,
        Row_Count,
        BufferAllocated_MB,
        BufferWaste_MB
    )
    SELECT
        db_name(database_id) Database_Name,
        obj.[name] Object_Name,
        bd.page_type as Page_Type,
        i.[name] Index_Name,
        i.[type_desc] Index_Type,
        obj.Data_Compression_Desc,
        sum(row_count) as Row_Count,
        (count_big(*) * 8192) / (1024 * 1024) as BufferAllocated_MB,
        sum(free_space_in_bytes) / (1024 * 1024) as BufferWaste_MB
    FROM sys.dm_os_buffer_descriptors AS bd
      LEFT JOIN
      (
       SELECT object_name(object_id) AS name
        ,index_id ,allocation_unit_id
                , object_id
                , data_compression_desc
       FROM sys.allocation_units AS au
        INNER JOIN sys.partitions AS p
          ON au.container_id = p.hobt_id
           AND (au.type = 1 OR au.type = 3)
       UNION ALL
       SELECT object_name(object_id) AS name
        ,index_id ,allocation_unit_id
                , object_id
                , data_compression_desc
       FROM sys.allocation_units AS au
        INNER JOIN sys.partitions AS p
          ON au.container_id = p.hobt_id
           AND au.type = 2
      ) AS obj
       ON bd.allocation_unit_id = obj.allocation_unit_id
    LEFT JOIN sys.indexes i on i.object_id = obj.object_id AND i.index_id = obj.index_id
    WHERE database_id = db_id()
    GROUP BY database_id, obj.name, obj.index_id , i.[name], i.[type_desc], obj.Data_Compression_Desc, bd.page_type;
    ';

    SELECT SUM(BufferAllocated_MB) AS BufferAllocated_MB, SUM(BufferWaste_MB) AS BufferWaste_MB
        FROM #BufferCacheAllocation;

    SELECT Database_Name, SUM(BufferAllocated_MB) AS BufferAllocated_MB, SUM(BufferWaste_MB) AS BufferWaste_MB
        FROM #BufferCacheAllocation
            GROUP BY Database_Name
                ORDER BY SUM(BufferAllocated_MB) DESC;

    SELECT Page_Type, Index_Type, Data_Compression_Desc
        , SUM(BufferAllocated_MB) AS Allocated_MB, SUM(BufferWaste_MB) AS BufferWaste_MB
        FROM #BufferCacheAllocation
            GROUP BY Page_Type, Index_Type, Data_Compression_Desc
                ORDER BY SUM(BufferAllocated_MB) DESC;

    SELECT * FROM #BufferCacheAllocation ORDER BY BufferAllocated_MB DESC;

    "Do not seek to follow in the footsteps of the wise. Instead, seek what they sought." - Matsuo Basho

  • Have you considered the space consumed by the plan cache?

  • Hi Eric, I am referring to the buffer pool, where data/index pages are kept.  I ran your query and have attached the result.  As you can see, only a portion of the 51GB RAM is being used, even though SQL Server says that it is using 51GB.  The PLE is at 160, so there is quite bit of RAM contention.  I have attached the output of your query for your review. 

    Hi Ed, yes, I  have a query that shows the breakdown of  all  memory  by  type, and the plan cache uses 4-5GB.  Total usage by all types is not even close to 51GB, there is usually a 20-30GB gap.

  • I've run Perfmon when PLE is in the 100-150 range and found the below:

    Counter Database Cache Memory  is average of 17GB, minimum 16GB, maximum 19GB.

    Counter  Free Memory is average 26GB, minimum 25GB, maximum 27GB.

    Counter Stolen Server Memory is average 10GB, minimum 10GB, maximum 10GB.

    Something  is not right, 26GB of free  RAM, and yet  PLE is 100-150GB  continuously. 

    Also, why is the Stolen Server Memory so high, how can I find out what is using it?

  • shahgols - Thursday, December 28, 2017 10:30 AM

    I've run Perfmon when PLE is in the 100-150 range and found the below:

    Counter Database Cache Memory  is average of 17GB, minimum 16GB, maximum 19GB.

    Counter  Free Memory is average 26GB, minimum 25GB, maximum 27GB.

    Counter Stolen Server Memory is average 10GB, minimum 10GB, maximum 10GB.

    Something  is not right, 26GB of free  RAM, and yet  PLE is 100-150GB  continuously. 

    Also, why is the Stolen Server Memory so high, how can I find out what is using it?

    You would have already run the queries for stolen memory when you ran through all of the queries from the link to troubleshooting memory.
    Stolen pages are available using sys.dm_os_memory_clerks

    Sue

  • Hi Sue, I must have not run that since it threw an error on SQL 2012. 

    Either way, I am still  baffled by this.  Might have to open a MS Support case.

  • shahgols - Thursday, December 28, 2017 12:07 PM

    Hi Sue, I must have not run that since it threw an error on SQL 2012. 

    Either way, I am still  baffled by this.  Might have to open a MS Support case.

    Then I would guess a lot of those queries you didn't run. The pages columns in sys.dm_os_memory_clerks changed from single pages and multipages to just pages in SQL Server 2012. I would guess that is related to the error you had.

    Sue

  • Hi Sue, which one of the queries can I run to understand why there is such a high free page count and such low PLE?

Viewing 15 posts - 1 through 15 (of 15 total)

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