Yes, yes, yes, finally!
It’s hardly a secret that I’m not a fan of scalar user-defined functions. I refer to them as ‘developer pit-traps’ due to the amount of times I’ve seen developers absolutely wreck their database performance by over-using them (or using them at all).
The main problem with them is that they haven’t been in-line, meaning the function gets evaluated on every single row, and the overhead from doing so is usually terrible.
One of the improvements in SQL Server 2019 is that scalar user-defined functions now are in-line. Not all of them, there are conditions that have to be met. Most scalar UDFs that I’ve seem in client systems will meet them, the not referencing table variables will probably be the main limiting factor.
The full requirements are laid out in the documentation: https://docs.microsoft.com/en-us/sql/relational-databases/user-defined-functions/scalar-udf-inlining
I’m going to use the same function that I used when I evaluated natively-compiled functions (https://www.sqlinthewild.co.za/index.php/2016/01/12/natively-compiled-user-defined-functions/), and run it against a table with 860k rows in it, both in compat mode 140 (SQL Server 2017) and compat mode 150 (SQL Server 2019)
CREATE FUNCTION dbo.DateOnly (@Input DATETIME)
RETURNS DATETIME
AS
BEGIN
RETURN DATEADD(dd, DATEDIFF (dd, 0, @Input), 0);
END
GO
As in the earlier post, I’ll use extended events to catch the performance characteristics.
First, something to compare against. The query, without functions, is:
SELECT DATEADD(dd, DATEDIFF (dd, 0, TransactionDate), 0) FROM Transactions
This takes, on average, 343ms to run, and 320ms of CPU time.
The results of the first test are impressive.
Compat Mode | Duration (ms) | CPU (ms) |
140 | 10 666 | 8594 |
150 | 356 | 353 |
I keep having people ask about SCHEMABINDING, so same test again, with the function recreated WITH SCHEMABINDING
Compat Mode | Duration (ms) | CPU (ms) |
140 | 5448 | 3818 |
150 | 325 | 320 |
Better, but still over an order of magnitude slower than the query without the function in SQL 2017 and earlier.
Last test, what about something with data access? I’ll switch to my Shipments and ShipmentDetails tables for this. The base query without the function is:
SELECT s.ShipmentID,
(SELECT SUM(Mass) AS TotalMass FROM ShipmentDetails sd WHERE sd.ShipmentID = s.ShipmentID) TotalShipmentMass
FROM Shipments s;
I’m writing it with a subquery instead of a join to keep it as similar as possible to the version with the function. It should be the same as if I had used a join though. That query takes, on average, 200ms, with 145ms CPU time.
There are 26240 rows in the Shipments table, and on average 34 detail rows per shipment. The function is:
CREATE FUNCTION dbo.ShipmentMass(@ShipmentID INT)
RETURNS NUMERIC(10,2)
AS
BEGIN
DECLARE @ShipmentMass NUMERIC(10,2);
SELECT @ShipmentMass = SUM(Mass) FROM ShipmentDetails sd WHERE sd.ShipmentID = @ShipmentID;
RETURN @ShipmentMass;
END
And the results are:
Compat Mode | Duration (ms) | CPU (ms) |
140 | 961 211 (16 minutes) | 959 547 |
150 | 3280 | 3272 |
The test under compat mode 140 had to be run overnight. 9 hours to run the query 25 times… And people wonder why I complain about scalar user-defined functions in systems.
Under compat mode 150 with the inline function it’s way better (3 seconds vs 16 minutes for a single execution), but it’s still over an order of magnitude slower than the same query with the subquery. I’ll test this again after RTM, but for the moment it look like my guidance for functions for SQL 2019 going forward is going to be that scalar functions that don’t access data are fine, but scalar functions that do should still be replaced by inline table-valued functions or no function at all, wherever possible.
It is interesting that the query with the inlined scalar UDF in SQL Server 2019 did not perform as well as the manually inlined version with the subquery. I’m curious – did SQL Server use 2 different query plans for these queries? Also, if you use a hand-crafted inline table-valued function, is performance for this query comparable to the manually inlined version?
I didn’t check the plans, and I was not testing in-line table valued functions. I know how they perform – equivalent to a subquery, since the parser treats them as parameterised views.
I’m told that this is expected behaviour, that the query without the scalar function should still be faster than the query with the scalar function, though far closer in performance than in older versions.