Tuesday, May 28, 2019

SQL Server memory node memory footprints

Day-in, day-out i use perfmon to monitor SQL Server resource utilization and behavior, because its observer overhead is so low.

But its useful to have a few TSQL queries in the stable, too, for adhoc use or if a given memory state needs to result in some action taken within SQL Server.

i'm sure there's a clever wayt to use 'pivot', 'unpivot' and/or 'cross apply' to make this query more elegant. But i just wanted to get this here somewhere. if i figure out a more elegant way to get the resultset i'll update this blog post.
~~~~~

;WITH dbc AS (SELECT node=instance_name, dbc = cntr_value
     FROM sys.dm_os_performance_counters 
     WHERE counter_name = 'Database Node Memory (KB)'),
stl AS (SELECT [node]=instance_name, stl = cntr_value
     FROM sys.dm_os_performance_counters
     WHERE counter_name = 'Stolen Node Memory (KB)'),
fre AS (SELECT [node]=instance_name, fre = cntr_value
     FROM sys.dm_os_performance_counters
     WHERE counter_name = 'Free Node Memory (KB)'),
tot AS (SELECT [node]=instance_name, tot = cntr_value
     FROM sys.dm_os_performance_counters
     WHERE counter_name = 'Total Node Memory (KB)'),
tgt AS (SELECT [node]=instance_name, tgt = cntr_value
     FROM sys.dm_os_performance_counters
     WHERE counter_name = 'Target Node Memory (KB)'),
fgn AS (SELECT [node]=instance_name, fgn = cntr_value
     FROM sys.dm_os_performance_counters
     WHERE counter_name = 'Foreign Node Memory (KB)')
SELECT [memNode] = dbc.[node], 
       [dbCache] = dbc.dbc, 
       [stolen]  = stl.stl, 
       [free]    = fre.fre,
       [total]   = tot.tot, 
       [target]  = tgt.tgt, 
       [foreign] = fgn.fgn
FROM dbc
JOIN stl ON dbc.[node] = stl.[node]
JOIN fre ON dbc.[node] = fre.[node]
JOIN tot ON dbc.[node] = tot.[node]
JOIN tgt ON dbc.[node] = tgt.[node]
JOIN fgn ON dbc.[node] = fgn.[node];


These results - in the order of their capture - are much more interesting.





Let's look at the results below a bit.
The target for the instance is 4 * 180, 991, 992 kb =  723, 967, 968 kb = 707, 000 mb.
Total for the instance is 883, 498, 216 = 862, 791 mb. 155, 791 mb is a pretty big overage.



Total foreign memory is 207, 386, 832 kb = 202, 506 mb. That's a lot of foreign memory.







Q.


Thursday, May 23, 2019

SQL Server 2016: Here a NUMA, there a NUMA... Part 2

*****
This post is a continued look at some memory behaviors explored earlier in the following blog post.

SQL Server 2017: here a NUMA, there a NUMA... Part 1
https://sql-sasquatch.blogspot.com/2019/05/sql-server-2017-here-numa-there-numa.html

The previous blog post gives detail around a significant performance degradation event experienced on a 4 node perf/scale test system. This blog post instead details observations from a production 4 node system.
*****

4x14 vcpus, 1472 total GB vRAM (368 GB per vNUMA node).

Max server memory set at 1375000 mb. 

See if you can spot the unexpected system state below.  🙂







The [db cache] on node 000 is ginormous!!

There is only 368 GB of vRAM on the vNUMA node.  Node 000 is accounting for [db cache] that alone approaches the full amount of vRAM on 3 vNUMA nodes!!

How does that happen if instance wide [total] memory stays constant at [max server memory], and [total] memory stays constant on the other 3 NUMA nodes at [target]?

Got memory counted twice.  Comparing [stolen] memory from all 4 nodes to the instance-wide measure of [stolen] memory shows that something's up 🙂  On this system, nodes 001, 002, and 003 each have a portion of their memory which they account for as [stolen] but node 000 accounts for as [db cache].



There were no free list stalls during this period, thankfully.Somehow the instance is able to eke along keeping a small amount of free memory throughout.



But there is still a cost to pay for this unusual memory state.

I suspect that the cost of cross-node accounting and double-counting the memory is in part reflected by latch waits.




Wednesday, May 15, 2019

MADPASS 2019 May 15 - perfmon black box & AMA

Nothing to see here yet :-)

This is a place holder for a follow-up blog post to tonight's 5 minute intro to the value of a locally run perfmon black box, followed by the AMA panel with myself, Joe Obbish, and John Eisbrener.

Once there's something of interest here I'll tweet the link to give it a proper introduction.

Windows groups Performance Monitor Users and Performance Log Users.
Error message when you try to access the Performance Monitor (Perfmon.exe) on a remote computer: "Access Is Denied"
https://support.microsoft.com/en-us/help/969639/


How to create a “black box” performance counter data collector
(Clint Huffman, 2014 May 23)
https://blogs.technet.microsoft.com/clinth/2014/05/23/how-to-create-a-black-box-performance-counter-data-collector/

My m.o. is to use a counters file. I typically keep the counters file in the same directory as my perfmon start script(s).

For example this text file lives at C:\perfmon\blackbox__counters.txt.

Note the final two lines - date and my name.  Because they don't match to legit counters these lines are ignored; i use this for commenting in my counters files.

\NUMA Node Memory(*)\Free & Zero Page List MBytes
\Paging File(_Total)\% Usage
\Memory\Pages Input/sec
\Memory\Pages Output/sec
\Network Interface(*)\Bytes Received/sec 
\Network Interface(*)\Bytes Sent/sec
\Processor Information(*,_Total)\% Processor Time
\LogicalDisk(*)\Current Disk Queue Length
\20190515
\Lonny Niederstadt -- Blackbox


The start script can be run interactively("Run as administrator"), but I also enjoy setting them to run on system start with schtasks.  It lives at C:\perfmon\blackbox__start.bat


:: local perfmon blackbox Lonny Niederstadt 20190515
setlocal enableextensions
cd /d "%~dp0"
logman.exe stop blackbox_%COMPUTERNAME%
logman.exe delete blackbox_%COMPUTERNAME%
logman.exe create counter blackbox_%COMPUTERNAME% -f csv -v mmddhhmm -max 500 -cf blackbox__counters.txt -o "C:\perfmon\blackbox_%computername%" -si 00:00:30 -cnf 24:00:00 -rf 672:00:00
logman.exe start blackbox_%COMPUTERNAME%
::pause

The real magic is in the "logman create counter" command.
logman create counter
https://docs.microsoft.com/en-us/windows-server/administration/windows-commands/logman-create-counter 

Additional resources:

https://techcommunity.microsoft.com/t5/Ask-The-Performance-Team/Two-Minute-Drill-LOGMAN-EXE/ba-p/373061

Monday, May 13, 2019

SQL Server 2017: here a NUMA, there a NUMA... Part 1

aka Performance Bamboozle

*****
This blog post considers a perf/scale testing system.  See a following blog post for similar concerns from a SQL Server 2016 production system.
SQL Server 2016: Here a NUMA, there a NUMA... Part 2
https://sql-sasquatch.blogspot.com/2019/05/sql-server-2016-here-numa-there-numa.html
*****

Let's observe a workload on SQL Server 2017 CU13, running on a 4x24 vcpu VM with 900 GB vRAM. [Max server memory] is set to 750 GB.  From 5:00 am to 12:30 pm [target server memory] is equal to [max server memory]; below I will refer to [target] only.


The yellow box marked in the graphs below is unusual.  Although CPU utilization generally trends with both active requests and parallel workers in the [default] workload group, CPU utilization is far lower in the yellow box than predicted by the number of active requests or parallel workers.  The end of the yellow box coincided with an intervention step.  My quick-thinking colleague Joe Obbish issued a [dbcc dropcleanbuffers] and the recovery was nothing short of miraculous.  But certainly that's not an operation to execute frequently on a busy system.  I'll be referring to the yellow box as a "performance bamboozle" for the remainder of this blog post.  I've gotta do something to keep myself amused.  What went wrong - and why did [dbcc dropcleanbuffers] help?



Only two DOP 8 queries ran for the majority of the yellow box.  Lets compare their Query Store details to those of similar queries with the same query_hash values.  All eight of the query executions detailed in the following 2 result sets ran at DOP 8; the particular queries of interest are highlighted in red.

Wow.  All 8 queries returned a single row.  All 8 had similar CPU ms, physical reads, logical reads, tempdb use, query memory use. But those two highlighted in red had elapsed time roughly 20 to 30 times that of the other queries. What happened?




The workers for these queries spent the majority of the yellow box time in sleep_task wait.  Often sleep_task is often ignored as a benign wait.

Read more about sleep_task waits in the
SQLSkills SQL Server Wait Type Library
https://www.sqlskills.com/help/waits/sleep_task/

Though perfmon includes details of several wait types in [\SQLServer:Wait Statistics(*)\*], sleep_task is not among them.

But perfmon offers other evidence of what was happening in those 2 queries.  Check out those free list stalls!!



The free list stalls call to mind the instance-wide perfmon counter [\SQLServer:Memory Manager\Free Memory (KB)].

SQL Server [total] memory is comprised of three categories: [database cache], [stolen], [free].

Just in case someone out there loves a little perfmon math as much as I do...

  [\SQLServer:Memory Manager\Database Cache Memory (KB)]
+ [\SQLServer:Memory Manager\Stolen Server Memory (KB)]
+ [\SQLServer:Memory Manager\Free Memory (KB)]
= [\SQLServer:Memory Manager\Total Server Memory (KB)]



It seems fairly intuitive that [\SQLServer:Memory Manager\Free Memory (KB)] would be pretty low when free list stalls are occurring.  And indeed that's what is seen in the graph below:the high plateau of free list stalls occurs during a valley of SQLOS free memory.


On this 4 vNUMA node vm, perfmon counters [\SQLServer:Memory Node(*)\Free Node Memory (KB)] will account for the portion of [\SQLServer:Memory Manager\Free Memory (KB)] on each SQLOS node.  The graph below shows that (although every now and then a stray errant value shows up in the individual node values).


The changes in free memory across the SQLOS nodes almost seem to predict something...


OK, let's look at the [\SQLServer:Memory Node(*)\Database Node Memory (KB)] counters.
Interesting that almost no database cache is listed on node 002 during the performance bamboozle.


When looking at [Stolen] memory in the next graph, something doesn't quite add up.  Some memory in the instance is being double-counted by SQLOS: counted on one node as [db cache] and on another as [stolen].  I've blogged about that briefly in the following two blog posts.

SQL Server 2016 Memory Accounting: A Suspicious Surprise 
http://sql-sasquatch.blogspot.com/2018/07/sql-server-2016-memory-accounting.html 

SQL Server 2016 Memory Accounting Part II: Another Suspicious Example
http://sql-sasquatch.blogspot.com/2018/10/sql-server-2016-memory-accounting-part.html

The massive amount of [stolen] memory on node 002 makes sense given the almost complete lack of [Db Cache] on node 002. It still looks kind of unusual.


~~~~~

Now, when free list stalls occur, one way to replenish the free lists is for clean buffer pool pages to be evicted by the lazy writer thread(s). Page writes can make clean pages out of dirty pages 🙂

So, when free list stalls occur, I expect to see page writes coming out of SQL Server.  But there weren't many page writes during this performance bamboozle.  Lazy writer wrote out a few pages.  Notice that as lazy writer wrote pages, the number of free list stalls slightly decreased. Checkpoint writes occurred up to the start of the performance bamboozle.  But not during.

There were no background writer writes, because the active databases were using automatic checkpoints rather than indirect checkpoints.


The slow pace of page writes contributed to the performance bamboozle. Or perhaps share a common underlying cause.

Note especially the second large bout of free list stalls at approximately 10:15 am.  During that round of free lists stalls, SQL Server page writes and lazy writer writes were plentiful.  That's how I expect the system to respond to free list stalls.

The [dbcc dropcleanbuffers] that Joe initiated to end the performance bamboozle was able to do something that the lazywriter was not able to do.  It broke a logjam, freeing up a bunch of memory within SQL Server [total] memory and allowing the lazywriter threads to get back to normal work.

~~~~~~~~~~

Many may already be familiar with the exceptional behavior shown in the next graph.  [Target server memory] is not as often enforced for SQL Server [total] memory as it used to be.  Batch mode columnstore queries especially seem prone to make [total] exceed [target].  This behavior is not unique to systems with multiple NUMA nodes; it can also be seen when there is a single SQLOS memory node.

Notice that [total] exceeds [target] almost immediately after the yellow box below, in addition to other times in the graph..



Description of [total] exceeding [target] can be seen in the following KB article, with a screenshot excerpt following.

Memory configuration and sizing considerations in SQL Server 2012 and later versions
https://support.microsoft.com/en-us/help/2663912/memory-configuration-and-sizing-considerations-in-sql-server-2012-and


For various reasons, I do not consider [total] > [target] to be a contributor to the performance bamboozle.  Rather, the brief time that [total] exceeded [target] after the performance bamboozle was a part of SQL Server recovering to normal behavior.

~~~~~~~~~~

The graph below shows this instance also experienced persistent and gradually accumulating [foreign] memory in the SQLOS memory nodes.  Fluctuation in the amount of [foreign] memory is somehow related to [total] exceeding [target].  This behavior is unique to systems with multiple NUMA nodes and multiple SQLOS memory nodes.


The persistent and accumulating [foreign] memory, similar to [total] > [target] does not seem to have been a contributor to the performance bamboozle.  Rather, the increase in total 


~~~~~~~~~~

At 9:31:07 top level memory blocks were allocated.



Harshdeep Singh discusses the role of top level memory blocks in maintaining free lists in the following blog post.

An In-depth look at memory – SQL Server 2012/2014
https://blogs.msdn.microsoft.com/sqljourney/2015/04/27/an-in-depth-look-at-memory-sql-server-20122014/

Late(r than expected) allocation of top level memory blocks may have contributed to the performance bamboozle.


Q.







dbcc MemoryStatus -- IO error??

No answers in this post, just a question I don't want to lose track of.

2019 May 7 I put this question to #sqlhelp:

[dbcc memorystatus] in 2017 cu13 gives information about IO errors. Is there another source for that error count or more details elsewhere? Nothing in the SQL Server error log, Windows event log.

https://twitter.com/sqL_handLe/status/1125806349978415109



No answer yet.

I set up a task via schtasks to send 'dbcc memorystatus' output to a file every 5 minutes for a memory investigation.  I thought it might shed some light on this information from 'dbcc memorystatus'.  Nope, not yet.
hhttps://twitter.com/sqL_handLe/status/1125806349978415109ttps://twitter.com/sqL_handLe/status/1125806349978415109

Here are a few of the results I scraped.  Not sure if 'IO error' is a count of errors, or indicating an error code for the most recent IO error.  Though there's seemingly no information for errors with some of these numbers.  It may be a count of errors within each checkpoint, or somesuch.  The two busy databases in this instance are both using automatic rather than indirect checkpoints.
 
May 11 time        Dirty     IO error
4:00:01          2382710         7685
4:05:01          1510246         2412
4:10:01          1076007        19739
4:15:01           364968         9050
4:20:00            44028        16855
4:25:00            28251         1653
4:30:00            23242         2674
4:35:00            24668        32750
4:40:00            25199       124190
4:50:01            26107         2079
4:55:00            25661        70204
5:00:00           909808        13664




I'll update this post if I learn anything exciting in the future.