SQL Server 2016 – Batch Mode Processing with Serial Plan

Hello Friends,

There are lots of features and improvements announced by Microsoft in SQL Server 2016, one of them is providing batch mode processing with 900 rows batch size. SQL Server 2016 uses batch mode processing even if the execution plan is a serial plan which was not possible with previous versions. Due to this improvement, our queries can run much faster, even if they are running with serial plan. Today, we will execute a query over the column store table under the compatibility level of SQL Server 2014 and SQL Server 2016. First, I’ll execute the query on database compatibility level 120 and you will notice that SQL Server will use row mode processing for serial plan:

USE [master]
GO
ALTER DATABASE [PartitionTruncate] SET COMPATIBILITY_LEVEL = 120
GO
USE [PartitionTruncate]
GO
DBCC DROPCLEANBUFFERS();
GO
Select id,balance,name from xtPartitionTruncate (NOLOCK) 
WHERE ID<6600000 ORDER BY name
OPTION (MAXDOP 1)
GO

SQL Server 2016 - Batch Mode Processing with Serial Plan

SQL Server 2016 - Batch Mode Processing with Serial Plan

SQL Server 2016 - Batch Mode Processing with Serial Plan

From the above execution plan, you can see that both operators are performing the row mode processing with compatibility level 120. Now, let me try to show you the same query execution plan with database compatibility level 130.

   
USE [master]
GO
ALTER DATABASE [PartitionTruncate] SET COMPATIBILITY_LEVEL = 130
GO
USE [PartitionTruncate]
GO
DBCC DROPCLEANBUFFERS();
GO
Select id,balance,name from xtPartitionTruncate (NOLOCK) 
WHERE ID<6600000 ORDER BY name
OPTION (MAXDOP 1)
GO

SQL Server 2016 - Batch Mode Processing with Serial Plan

SQL Server 2016 - Batch Mode Processing with Serial Plan

SQL Server 2016 - Batch Mode Processing with Serial Plan

From the above execution plan, you can see that both operators are performing the batch mode processing with compatibility level 130. This is really a great improvement in terms of performance for the SQL Server Instances where DBA’s made changes to the cost threshold for parallelism. Queries which have cost less than the cost threshold for parallelism can also run much faster using batch mode processing. Here I am not showing you the execution time in both the cases. You can compare execution time and can see the importance of batch mode processing.

HAPPY LEARNING!

Regards:
Prince Kumar Rastogi

Like us on FaceBook | Join the fastest growing SQL Server group on FaceBook

Follow Prince Rastogi on Twitter | Follow Prince Rastogi on FaceBook

   

About Prince Rastogi

Prince Rastogi is working as Database Administrator at Elephant Insurance, Richmond. He is having more than 8 years of experience and worked in ERP Domain, Wealth Management Domain. Currently he is working in Insurance domain. In the starting of his career he was working on SQL Server, Internet Information Server and Visual Source Safe. He is post graduate in Computer Science. Prince is ITIL certified professional. Prince likes to explore technical things for Database World and Writing Blogs. He is Technical Editor and Blogger at SQLServerGeeks.com. He is a regular speaker at DataPlatformDay events in Delhi NCR. He has also presented some in depth sessions about SQL Server in SQL Server Conferences in Bangalore.

View all posts by Prince Rastogi →

Leave a Reply

Your email address will not be published.