How to avoid using variables in WHERE clause
Parameter sniffing is your friend almost all of the time and you should write your queries so that it can be used. Parameter sniffing helps building the plan for you using the parameter values available when the query is compiled. The dark side of parameter sniffing is when the values used when compiling the query is not optimal for the queries to come.
The query in a stored procedure is compiled when the stored procedure is executed, not when the query is executed so the values that SQL Server has to deal with here...
CREATE PROCEDURE WeeklyProc(@endDate DATE)
AS
BEGIN
DECLARE @startDate DATE = DATEADD(DAY, -6, @endDate)
SELECT
-- Stuff
FROM Sale
WHERE SaleDate BETWEEN @startDate AND @endDate
END
is a known value for @endDate
and an unknown value for @startDate
. That will leave SQL Server to guessing on 30% of the rows returned for the filter on @startDate
combined with whatever the statistics tells it for @endDate
. If you have a big table with a lot of rows that could give you a scan operation where you would benefit most from a seek.
Your wrapper procedure solution makes sure that SQL Server sees the values when DateRangeProc
is compiled so it can use known values for both @endDate
and @startDate
.
Both your dynamic queries leads to the same thing, the values are known at compile-time.
The one with a default null value is a bit special. The values known to SQL Server at compile-time is a known value for @endDate
and null
for @startDate
. Using a null
in a between will give you 0 rows but SQL Server always guess at 1 in those cases. That might be a good thing in this case but if you call the stored procedure with a large date interval where a scan would have been the best choice it may end up doing a bunch of seeks.
I left "Use the DATEADD() function directly" to the end of this answer because it is the one I would use and there is something strange with it as well.
First off, SQL Server does not call the function multiple times when it is used in the where clause. DATEADD is considered runtime constant.
And I would think that DATEADD
is evaluated when the query is compiled so that you would get a good estimate on the number of rows returned. But it is not so in this case.
SQL Server estimates based on the value in the parameter regardless of what you do with DATEADD
(tested on SQL Server 2012) so in your case the estimate will be the number of rows that is registered on @endDate
. Why it does that I don't know but it has to do with the use of the datatype DATE
. Shift to DATETIME
in the stored procedure and the table and the estimate will be accurate, meaning that DATEADD
is considered at compile time for DATETIME
not for DATE
.
So to summarize this rather lengthy answer I would recommend the wrapper procedure solution. It will always allow SQL Server to use the values provided when compiling the the query without the hassle of using dynamic SQL.
PS:
In comments you got two suggestions.
OPTION (OPTIMIZE FOR UNKNOWN)
will give you an estimate of 9% of rows returned and OPTION (RECOMPILE)
will make SQL Server see the parameter values since the query is recompiled every time.
Ok, I have two possible solutions for you.
First I'm wondering if this will allow for increased parameterization. I haven't had a chance to test it out but it might work.
CREATE PROCEDURE WeeklyProc(@endDate DATE, @startDate DATE)
AS
BEGIN
IF @startDate IS NULL
SET @startDate = DATEADD(DAY, -6, @endDate)
SELECT
-- Stuff
FROM Sale
WHERE SaleDate BETWEEN @startDate AND @endDate
END
The other option takes advantage of the fact you are using fixed time frames. First create a DateLookup table. Something like this
CurrentDate 8WeekStartDate 8WeekEndDate etc
Fill it in for every date between now and the next century. This is only ~36500 rows so a fairly small table. Then change your query like this
IF @Range = '8WeekRange'
SELECT
-- Stuff
FROM Sale
JOIN DateLookup
ON SaleDate BETWEEN [8WeekStartDate] AND [8WeekEndDate]
WHERE DateLookup.CurrentDate = GetDate()
Obviously this is just an example and could certainly be written better but I've had a lot of luck with this type of table. Particularly since it is a static table and can be indexed like crazy.