SQL Server 2014 – TokenAndPermUserStore Clear Decreases CPU Usage Temporarily

sql serversql server 2014

Intro

In short, there are a lot of ad hoc queries occuring on my server, from an application which I do not control and cannot change (Even pushing indexes is hard, and they use many heaps… ).

Specs

OS – Windows Server 2012 R2 (Primary Node)
SQL Server 2014 – 12.0.5546

Always On AG With the secondary synchronous node with the same hardware + Build.

Memory:

We can only use 12 of the 24 cores for sql server due to licensing ( I did not do this). It's quite easy to spot which 12 cores ;).
Cpu usage

The problem

Now as to my problem. At the moment, every 30 minutes we clear out the "TokenAndPermUserStore". This was happening on the server even before it came in my hands. We did this with the command:

DBCC FREESYSTEMCACHE ('TokenAndPermUserStore') 

I use this query to check the cache:

SELECT SUM(pages_kb) / 1024  AS 
   "CurrentSizeOfTokenCache(mb)" 
   FROM sys.dm_os_memory_clerks 
   WHERE name = 'TokenAndPermUserStore'

Right after the clear this is the cache size:

CurrentSizeOfTokenCache(mb)
1602

At a certain point in time, for example 15 Minutes after the clear this is the cache size:

CurrentSizeOfTokenCache(mb)
1976

Update:
Now, when CPU used is stable again (40% used (20% on monitoring), the cache is way below the lowest point it was when CPU usage was high.

CurrentSizeOfTokenCache(mb)
1281 

An example of yesterday:

The drops are very present on this picture of yesterday:
(Note as we can use 12 of the 24 cores, 50 % Means 100% in the monitoring software, in other words the cpu usage will probably not exceed 50% because it is dedicated to sql server only)

enter image description here

One important thing to note is, we added two important indexes on the top queries yesterday, because of the CPU almost flat lining, which helped for a short period, but the cpu rose to the same level again, with no noticable queries that should hammer our system this hard.

The question

Now, to my question, today, i tried clearing the cache more frequently, by executing

DBCC FREESYSTEMCACHE ('TokenAndPermUserStore')  

a few times manually.
But it seemed, that after around 20 seconds, the cpu usage came back with a vengeance.

You can clearly see the three dips after executing the command, but it coming back rather fast in the picture below.

enter image description here

Should I schedule the command more, should i look at other changes?

I know that this issue was prevalent in SQL Server 2005, but this is SQL Server 2014. The queries are sp_executesql type queries.

If you need more information, or clarification, don't hesitate to let me know.

Update as of 05/12/2018

Query plan:
https://www.brentozar.com/pastetheplan/?id=BkUKKVByV

–> Paste the plan is creating the same link for the three plans found. I tried adding all three XML plans found in the cache for the same query, each with 10 executions, and got the same link for each one.

Query used

    SELECT 
  text, execution_count,
dm_exec_query_stats.creation_time, dm_exec_query_plan.query_plan
FROM sys.dm_exec_query_stats 
CROSS APPLY sys.dm_exec_sql_text(dm_exec_query_stats.plan_handle)
CROSS APPLY sys.dm_exec_query_plan(plan_handle)

results for three of the same queries:

enter image description here

I do want to note, the queries are using SNAPSHOT ISOLATION , by setting it before executing the query, and using the hints OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)

Query 1

(@SV1 nvarchar(8),@SV2 nvarchar(8),@SV3 nvarchar(8),@SV4 nvarchar(8),@SV5 nvarchar(8),@SV6 nvarchar(8),@SV7 nvarchar(8),@SV8 nvarchar(8),@SV9 nvarchar(8),@SV10 nvarchar(8),@SV11 nvarchar(8),@SV12 nvarchar(8),@SV13 nvarchar(8),@SV14 nvarchar(8),@SV15 nvarchar(8),@SV16 nvarchar(8),@SV17 nvarchar(8),@SV18 nvarchar(8),@SV19 nvarchar(8))  IF @@TRANCOUNT = 0 SET TRANSACTION ISOLATION LEVEL SNAPSHOT  SELECT AA.[SourceCode],AA.[DOUBLEMEDICATIONSVALIDATED],AA.[BSTNUM],AA.[MUTKOD],AA.[VERVALLEN],AA.[BACKUPID],AA.[LAATSTE],AA.[ExterneCode],AA.[PRKODE],AA.[NMMEMO],AA.[NMETIK],AA.[NMNM40],AA.[NMNAAM],AA.[PRNMNR],AA.[PRKBST],AA.[GPKODE],AA.[DRMLGEN],AA.[Anticoagulant],AA.[HPKSubstancesDiff],AA.[HPKCIsDiff],AA.[HPKUndesiredGroupsDiff]  FROM [dbo].[ZINDEX_050] AA  WHERE EXISTS (SELECT NULL  FROM (SELECT TOP 100 PERCENT  A.[BSTNUM],A.[MUTKOD],A.[VERVALLEN],A.[BACKUPID],A.[DMPRKA],A.[DMPRKB],A.[DMCODE],A.[DMGRDCODE]  FROM [dbo].[ZINDEX_671] A  WHERE ((A.[VERVALLEN] = 0 OR A.[VERVALLEN] IS NULL) AND ((A.[DMPRKA] = @SV1 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV4) OR  (A.[DMPRKA] = @SV5 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV6 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV7) OR  (A.[DMPRKA] = @SV8 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV9 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV10) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV11) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV12) OR  (A.[DMPRKA] = @SV13 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV14) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV15) OR  (A.[DMPRKA] = @SV16 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV17 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV18 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV19)))  ) A  WHERE AA.[PRKODE] = A.[DMPRKA])  OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)    SELECT AB.[SourceCode],AB.[DOUBLEMEDICATIONSVALIDATED],AB.[BSTNUM],AB.[MUTKOD],AB.[VERVALLEN],AB.[BACKUPID],AB.[LAATSTE],AB.[ExterneCode],AB.[PRKODE],AB.[NMMEMO],AB.[NMETIK],AB.[NMNM40],AB.[NMNAAM],AB.[PRNMNR],AB.[PRKBST],AB.[GPKODE],AB.[DRMLGEN],AB.[Anticoagulant],AB.[HPKSubstancesDiff],AB.[HPKCIsDiff],AB.[HPKUndesiredGroupsDiff]  FROM [dbo].[ZINDEX_050] AB  WHERE EXISTS (SELECT NULL  FROM (SELECT TOP 100 PERCENT  A.[BSTNUM],A.[MUTKOD],A.[VERVALLEN],A.[BACKUPID],A.[DMPRKA],A.[DMPRKB],A.[DMCODE],A.[DMGRDCODE]  FROM [dbo].[ZINDEX_671] A  WHERE ((A.[VERVALLEN] = 0 OR A.[VERVALLEN] IS NULL) AND ((A.[DMPRKA] = @SV1 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV4) OR  (A.[DMPRKA] = @SV5 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV6 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV7) OR  (A.[DMPRKA] = @SV8 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV9 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV10) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV11) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV12) OR  (A.[DMPRKA] = @SV13 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV14) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV15) OR  (A.[DMPRKA] = @SV16 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV17 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV18 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV19)))  ) A  WHERE AB.[PRKODE] = A.[DMPRKB])  OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)    SELECT A.[BSTNUM],A.[MUTKOD],A.[VERVALLEN],A.[BACKUPID],A.[DMPRKA],A.[DMPRKB],A.[DMCODE],A.[DMGRDCODE]  FROM [dbo].[ZINDEX_671] A  WHERE ((A.[VERVALLEN] = 0 OR A.[VERVALLEN] IS NULL) AND ((A.[DMPRKA] = @SV1 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV4) OR  (A.[DMPRKA] = @SV5 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV6 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV7) OR  (A.[DMPRKA] = @SV8 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV9 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV10) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV11) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV12) OR  (A.[DMPRKA] = @SV13 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV14) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV15) OR  (A.[DMPRKA] = @SV16 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV17 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV18 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV19)))  ORDER BY A.[DMPRKA] ASC,A.[DMPRKB] ASC  OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)      

Query 2

(@SV1 nvarchar(8),@SV2 nvarchar(8),@SV3 nvarchar(8),@SV4 nvarchar(8),@SV5 nvarchar(8),@SV6 nvarchar(8),@SV7 nvarchar(8),@SV8 nvarchar(8),@SV9 nvarchar(8),@SV10 nvarchar(8),@SV11 nvarchar(8),@SV12 nvarchar(8),@SV13 nvarchar(8),@SV14 nvarchar(8),@SV15 nvarchar(8),@SV16 nvarchar(8),@SV17 nvarchar(8),@SV18 nvarchar(8),@SV19 nvarchar(8))  IF @@TRANCOUNT = 0 SET TRANSACTION ISOLATION LEVEL SNAPSHOT  SELECT AA.[SourceCode],AA.[DOUBLEMEDICATIONSVALIDATED],AA.[BSTNUM],AA.[MUTKOD],AA.[VERVALLEN],AA.[BACKUPID],AA.[LAATSTE],AA.[ExterneCode],AA.[PRKODE],AA.[NMMEMO],AA.[NMETIK],AA.[NMNM40],AA.[NMNAAM],AA.[PRNMNR],AA.[PRKBST],AA.[GPKODE],AA.[DRMLGEN],AA.[Anticoagulant],AA.[HPKSubstancesDiff],AA.[HPKCIsDiff],AA.[HPKUndesiredGroupsDiff]  FROM [dbo].[ZINDEX_050] AA  WHERE EXISTS (SELECT NULL  FROM (SELECT TOP 100 PERCENT  A.[BSTNUM],A.[MUTKOD],A.[VERVALLEN],A.[BACKUPID],A.[DMPRKA],A.[DMPRKB],A.[DMCODE],A.[DMGRDCODE]  FROM [dbo].[ZINDEX_671] A  WHERE ((A.[VERVALLEN] = 0 OR A.[VERVALLEN] IS NULL) AND ((A.[DMPRKA] = @SV1 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV4) OR  (A.[DMPRKA] = @SV5 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV6 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV7) OR  (A.[DMPRKA] = @SV8 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV9 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV10) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV11) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV12) OR  (A.[DMPRKA] = @SV13 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV14) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV15) OR  (A.[DMPRKA] = @SV16 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV17 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV18 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV19)))  ) A  WHERE AA.[PRKODE] = A.[DMPRKA])  OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)    SELECT AB.[SourceCode],AB.[DOUBLEMEDICATIONSVALIDATED],AB.[BSTNUM],AB.[MUTKOD],AB.[VERVALLEN],AB.[BACKUPID],AB.[LAATSTE],AB.[ExterneCode],AB.[PRKODE],AB.[NMMEMO],AB.[NMETIK],AB.[NMNM40],AB.[NMNAAM],AB.[PRNMNR],AB.[PRKBST],AB.[GPKODE],AB.[DRMLGEN],AB.[Anticoagulant],AB.[HPKSubstancesDiff],AB.[HPKCIsDiff],AB.[HPKUndesiredGroupsDiff]  FROM [dbo].[ZINDEX_050] AB  WHERE EXISTS (SELECT NULL  FROM (SELECT TOP 100 PERCENT  A.[BSTNUM],A.[MUTKOD],A.[VERVALLEN],A.[BACKUPID],A.[DMPRKA],A.[DMPRKB],A.[DMCODE],A.[DMGRDCODE]  FROM [dbo].[ZINDEX_671] A  WHERE ((A.[VERVALLEN] = 0 OR A.[VERVALLEN] IS NULL) AND ((A.[DMPRKA] = @SV1 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV4) OR  (A.[DMPRKA] = @SV5 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV6 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV7) OR  (A.[DMPRKA] = @SV8 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV9 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV10) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV11) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV12) OR  (A.[DMPRKA] = @SV13 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV14) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV15) OR  (A.[DMPRKA] = @SV16 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV17 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV18 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV19)))  ) A  WHERE AB.[PRKODE] = A.[DMPRKB])  OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)    SELECT A.[BSTNUM],A.[MUTKOD],A.[VERVALLEN],A.[BACKUPID],A.[DMPRKA],A.[DMPRKB],A.[DMCODE],A.[DMGRDCODE]  FROM [dbo].[ZINDEX_671] A  WHERE ((A.[VERVALLEN] = 0 OR A.[VERVALLEN] IS NULL) AND ((A.[DMPRKA] = @SV1 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV4) OR  (A.[DMPRKA] = @SV5 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV6 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV7) OR  (A.[DMPRKA] = @SV8 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV9 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV10) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV11) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV12) OR  (A.[DMPRKA] = @SV13 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV14) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV15) OR  (A.[DMPRKA] = @SV16 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV17 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV18 AND A.[DMPRKB] = @SV2) OR  (A.[DMPRKA] = @SV3 AND A.[DMPRKB] = @SV19)))  ORDER BY A.[DMPRKA] ASC,A.[DMPRKB] ASC  OPTION (KEEP PLAN, KEEPFIXED PLAN, LOOP JOIN)   

It hurts to look at, i know.

Compiles even with forced parameterization

The compiles/sec matches batches/Sec almost 1 on 1, even when enabling forced parameterization.
Which is why the batches/sec line is hidden (it is behind the compiles/sec line).

enter image description here

Perfmon stats:

enter image description here

Queries, CPU , I/O when cpu is around 80% and when it is around 40%

The aggreggates of queries executed in the timeframe 1u05 PM – 1u25 PM today (80% Cpu usage) :
enter image description here

Cpu usage:
enter image description here

There is a difference with when cpu usage is lower 2u05 PM – 2u25PM today (40% cpu usage)
enter image description here

CPU Usage:

enter image description here

The first one is the one where we added an index when we saw issues, and made the cpu usage less.

Extra queries with checks and more info:

   select count(*) as amount_of_USERSTORE_TOKENPERM from sys.dm_os_memory_clerks
   where type = 'USERSTORE_TOKENPERM'

amount_of_USERSTORE_TOKENPERM
15190



     select count(*)  as amount_of_connections from sys.dm_exec_connections 
amount_of_connections
10004


       select  value_in_use from sys.configurations
       where name like '%access check cache bucket count%'

value_in_use
0
          select value_in_use from sys.configurations
       where name like '%access check cache quota%'
value_in_use
0

Best Answer

Than you all for your time and effort in finding a solution. Especially @David Browne - Microsoft since he was correct by letting me know that we should patch.

We had a meeting with the dba's, the application owners and the technical team of the application vendor.

In this meeting it came to light that the same issue is present for the other clients that the vendor has, due to the nature of the application and its code.

Similar to this.

The solution that has helped their other clients with this issue, is to upgrade to SQL Server 2014 CU7 or SP3, which we will be doing as soon as possible (SP3 preferably), which should put an end to the 'tokenandpermuserstore' issues.