Sudden PLE Drop Possible Without Memory Pressure?

  • My SQL Server is a virtual machine, running on ESX 4.1 and configured as follows:

    - 28GB of Memory, 21500 configured in Max Server Memory

    - Reservation is set in vcenter to 28GB, so there should be no balloon driver issues

    - SQL Service is configured for lock pages in memory

    - According to sys.dm_os_performance_counters, Target Server Memory and Total Server Memory are equal, at 537600KB, i.e. approximately 5GB

    - Optimize for Ad Hoc Workflows is enabled

    I know that the Page Life Expectancy value itself isn't necessarily important, but rather the overall PLE trend. We've had sudden drops in it lately during periods of heavy use of one of our web sites using the server as a backend. During the drops, performance in one of our critical web applications slows to a crawl. What I don't understand, is why SQL is only using 5GB of memory if it has 21.5GB available to it. Shouldn't it be caching as much as possible in the buffer pool? It was my understanding that SQL would take as much memory as it could, but this doesn't seem to be the case. The general consensus on the net seems to be that adding memory to a server is a quick and dirty way of working around PLE issues caused by poorly written queries, but if the server is only using a fraction of the memory available to it, why would increasing the memory help?

    Thanks,

    Tim

  • Okay, after reading through everything I could get my hands on regarding SQL memory, I think I've identified the culprit. Per VMware's recommendation, I had enabled large page allocation. However, what they fail to mention is that one very large consequence of this is that dynamic allocation of memory to the buffer pool is disabled, and that what SQL can allocate at startup is what you get. It looks like my instance of SQL Server was only able to grab enough memory to allocate 5GB to the buffer pool, hence the odd looking values in the DMVs. When I disabled Large Page Allocation and restarted SQL, the amount of memory being used by SQL climbed to the max, and the buffer pool almost tripled in size.

    Guess I learned a lot today 🙂

  • timothy.lazarus (3/9/2014)


    Okay, after reading through everything I could get my hands on regarding SQL memory, I think I've identified the culprit. Per VMware's recommendation, I had enabled large page allocation. However, what they fail to mention is that one very large consequence of this is that dynamic allocation of memory to the buffer pool is disabled, and that what SQL can allocate at startup is what you get. It looks like my instance of SQL Server was only able to grab enough memory to allocate 5GB to the buffer pool, hence the odd looking values in the DMVs. When I disabled Large Page Allocation and restarted SQL, the amount of memory being used by SQL climbed to the max, and the buffer pool almost tripled in size.

    Guess I learned a lot today 🙂

    Thanks to your post, I did, too! Thank you for taking the time. I really appreciate it.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • The technical details on large page allocation: http://blogs.msdn.com/b/psssql/archive/2009/06/05/sql-server-and-large-pages-explained.aspx

    The two limitations with large page allocations are that the memory must be contiguous and that the memory allocation is static once allocated (no more memory can be allocated or released). If there are other things allocating memory you can easily end up with multiple chunks of memory that combined exceed SQL's max server memory, but are each much smaller. This is almost expected with later OSs, because they randomise the memory addresses for apps and kernal code to avoid some overflow attacks.

    The contiguous requirement can mean that SQL takes quite some time to start and once it has, it's got much less memory than it's allowed to use.

    To be honest, large page allocations is not something I would generally recommend.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Thanks - after I read that yesterday, I had a sudden ah ha moment. I would definitely agree that if asked now, I wouldn't recommend it either.

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

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