• Home
  • SQL Server
    • Articles
    • T-SQL Puzzles
    • Output Puzzles
    • Interview Questions
    • Performance Tuning
    • SQL SERVER On Linux
    • Resources
  • SSRS
    • SSRS Articles
    • Interview Questions
  • SSAS
    • SSAS Articles
    • DAX
  • SQL Puzzles
  • Interview Questions
    • SQL Interview Questions
    • Data Interview Questions
  • Python Interview Puzzles
  • New Features(SQL SERVER)
    • SQL SERVER 2017
    • SQL SERVER 2016
    • SQL SERVER On Linux
  • Social
    • Expert Exchange
      • Top Expert in SQL
      • Yearly Award
      • Certifications
      • Achievement List
      • Top Expert of the Week
    • HackerRank (SQL)
    • StackOverflow
    • About Me
      • Contact Me
      • Blog Rules

Improving my SQL BI Skills

Improving my SQL BI Skills

Daily Archives: June 19, 2015

Avoid Using Function in WHERE Clause. Why?

19 Friday Jun 2015

Posted by Pawan Kumar Khowal in SQL Performance Tuning

≈ 3 Comments

Tags

26 performance tuning questions and solutions, Avoid SQL Server functions in the WHERE clause for Performance, Avoid Using Function in WHERE Clause – Scan to Seek, Avoid Using Functions in WHERE Clause tutorial and example, Functions in the WHERE Clause, How to avoid convert function in the where clause, How to tune SQL queries, Increase SQL Server performance avoid using functions in Where Clause, Interview questions for SQL Server Performance Tuning, Looking for SQL Optimization Interview Questions, performance sql server, Performance tips for faster SQL queries, Performance Tuning, Performance Tuning for SQL Server, Query Optimization, Query Performance Tuning, sql - How do I avoid functions like UPPER in where clause, SQL Complex Queries, SQL Optimization Interview Questions, sql performance, sql performance and tuning, sql performance explained pdf, sql performance tips, SQL Performance Tuning, sql performance tuning and optimization, sql performance tuning interview questions, sql performance tuning tips, SQL Query Optimizer, SQL Query Tuning or Query Optimization, SQL Server 2008 Query Performance Tuning Distilled, SQL SERVER Interview questions, SQL server optimization interview questions and answers, sql server performance query, sql server performance slow, SQL Server Performance Tuning, SQL Server Performance Tuning Tips, SQL SERVER Tips, SQL Tuning Overview, SQL Where Clause Performance, T-SQL Best Practices - Don't Use Scalar Value Functions in Where Clause, Tips for SQL Database Tuning and Performance, Top 10 performance tuning tips for relational databases, WHERE Clause Functions: A Word of Caution


Avoid Using Function in WHERE Clause. Why?

Download PDF – Avoid functions in Where Clause? Why ?

SQL Server has many functions that can be used in your WHERE clause and in the SELECT clause. Now these functions can be user defined or inbuilt. These functions normally provide functionality which would be very difficult to get without these functions. Now when these functions are used improperly in the WHERE clause these functions can cause major performance issues. When these same functions are used in the WHERE clause this forces SQL Server query optimizer to do a table scan or index scan to get the desired results instead of doing an index seek if there is an index that can be used.

The reason for this is that SQL Server has to call the function for each value of the column and match that with the matching criteria.

Some examples are given below that shows using a function in the WHERE clause can affect performance. Add actual execution plan and statistics IO ON for better understanding.

Let’s say we have a table called CustomerInfo with around 20K records. This Customerinfo table has 3 columns named (CustomerID, CustomerName, and ModifiedDate). This table also has 2 indexes which are given below-

index_name index_description index_keys
Ix_ModifiedDate nonclustered located on PRIMARY ModifiedDate
PK__Customer clustered, unique, primary key located on PRIMARY CustomerID

 Now let’s say we wanted to find out below all modified dates when ModifiedDate = ‘1947-08-29’. So to satisfy above query we wrote below query –

--

SELECT ModifiedDate FROM CustomerInfo WHERE ModifiedDate = '1947-08-29'

--

But above query will not return anything since the Modified Date column is of type DateTime. So we have to modify our query. So we came up with a new query.

--

SELECT ModifiedDate FROM CustomerInfo WHERE CAST(CONVERT(VARCHAR(10),ModifiedDate,101) AS DATETIME) = '1947-08-29'

--


Now let’s check the execution plan of the above query. Now with the below execution plan we can clearly find out 2 bad things. One is that we are having NonClustered index scan and the other thing is that we have a warning due to column data type conversion. The culprit here is the functions we are using in the where clause.

Pawan Kumar Khowal - Where Clause 1


Now let’s modify the above query and check out what happens. Here we are getting Index seek.

--

SELECT ModifiedDate FROM CustomerInfo
WHERE ModifiedDate >= '1947-08-29' AND ModifiedDate < '1947-08-30'

--

Now one of the best things in SSMS is that we have run 2 queries simultaneously and compare how much each query costs. First query is taking 95% of the cost and seconds query is taking only 5% of the cost. Now the first query is reading all the records from the leaf node that’s why we have Non Clustered Scan instead of seek.

Pawan Kumar Khowal - Where Clause 2

Now check out the difference between logical reads (1 Logical Read = 1 8KB Page). The first query is having 47 logical reads and in second case the query is having only 2 logical read because we are seeking index.

Pawan Kumar Khowal - Where Clause 3

In the second query we are using range based seeks. Hence always try not to use functions with the columns in the where clause. Always try to rewrite the query so that we can get good performance.

Now let’s try some more examples. In below example we are finding modified date for a particular year.

Pawan Kumar Khowal - Where Clause 4

In the above example in the first query is using Year function on Modified date to pick up the year and then we are matching that year with value 1947. That’s why we are getting a NonClustered Scan as SQL Server has to read all the values from leaf node. In the second query we are using where clause effectively that’s why we are getting a NonClustered Index seek, basically it is a range based seek which is much more efficient as we have read less number of data pages.

Let’s have one more example. Explanation is not required in that case. It’s an excellent way to use Where clause to get Seek. Let’s say you want to fetch records less than a date – One Year.
E.g. Modified date < ‘1948-12-29’ – 1 Year.
Now check out the queries below.

--

SELECT ModifiedDate FROM CustomerInfo
WHERE DATEADD(YEAR,1,ModifiedDate) < '1948-12-29'

SELECT ModifiedDate FROM CustomerInfo
WHERE ModifiedDate < DATEADD(YEAR,-1,'1948-12-29')

--

Now check the execution plans below. Clearly we can see that second query is taking only 6% of the total cost and the first query is taking 96% of the cost. That’s why second query is a clear winner in this case.

Pawan Kumar Khowal - Where Clause 5

Summary

When we are checking things for performance always try to find out these small things. These can help you queries performance greatly. We are reducing I/O by reading less data pages. So by not using functions in the WHERE clause we can provide big performance gains. We just have to tweak where clause. That should be easy.

That’s all folks, I hope you’ve enjoyed learning about Avoid functions in the where clause, and I’ll see you soon with more “Performance Tuning” articles.
Thanks !

Pawan Kumar Khowal

MSBISKills.com

Share this

  • LinkedIn
  • Facebook
  • Twitter
  • WhatsApp
  • Email

Blog Stats

  • 1,086,921 hits

Enter your email address to follow this blog and receive notifications of new posts by email.

Join 1,131 other subscribers

Pawan Khowal

502 SQL Puzzles with answers

Achievement - 500 PuzzlesJuly 18, 2018
The big day is here. Finally presented 500+ puzzles for SQL community.

200 SQL Server Puzzle with Answers

The Big DayAugust 19, 2016
The big day is here. Completed 200 SQL Puzzles today

Archives

June 2015
M T W T F S S
1234567
891011121314
15161718192021
22232425262728
2930  
« May   Jul »

Top Articles

  • pawankkmr.wordpress.com/2…
  • pawankkmr.wordpress.com/2…
  • pawankkmr.wordpress.com/2…
  • pawankkmr.wordpress.com/2…
  • pawankkmr.wordpress.com/2…

Archives

  • October 2020 (29)
  • September 2018 (2)
  • August 2018 (6)
  • July 2018 (25)
  • June 2018 (22)
  • May 2018 (24)
  • April 2018 (33)
  • March 2018 (35)
  • February 2018 (53)
  • January 2018 (48)
  • December 2017 (32)
  • November 2017 (2)
  • October 2017 (20)
  • August 2017 (8)
  • June 2017 (2)
  • March 2017 (1)
  • February 2017 (18)
  • January 2017 (2)
  • December 2016 (5)
  • November 2016 (23)
  • October 2016 (2)
  • September 2016 (14)
  • August 2016 (6)
  • July 2016 (22)
  • June 2016 (27)
  • May 2016 (15)
  • April 2016 (7)
  • March 2016 (5)
  • February 2016 (7)
  • December 2015 (4)
  • October 2015 (23)
  • September 2015 (31)
  • August 2015 (14)
  • July 2015 (16)
  • June 2015 (29)
  • May 2015 (25)
  • April 2015 (44)
  • March 2015 (47)
  • November 2012 (1)
  • July 2012 (8)
  • September 2010 (26)
  • August 2010 (125)
  • July 2010 (2)

Article Categories

  • Analysis Services (6)
    • DAX (6)
  • Data (2)
    • Data warehousing (2)
  • Integration Services (2)
  • Magazines (3)
  • Python (29)
  • Reporting Services (4)
  • SQL SERVER (820)
    • Download SQL Interview Q's (212)
    • SQL Concepts (323)
    • SQL Performance Tuning (155)
    • SQL Puzzles (331)
    • SQL SERVER 2017 Linux (6)
    • SQL Server Interview Questions (308)
    • SQL SERVER Puzzles (332)
    • T SQL Puzzles (547)
    • Tricky SQL Queries (439)
  • UI (30)
    • ASP.NET (5)
    • C# (13)
    • CSS (9)
    • OOPS (3)
  • Uncategorized (5)

Recent Posts

  • Python | The Print and Divide Puzzle October 30, 2020
  • Python | Count consecutive 1’s from a list of 0’s and 1’s October 30, 2020
  • Python | How to convert a number into a list of its digits October 26, 2020
  • Python | Validate an IP Address-IPV6(Internet Protocol version 6) October 26, 2020
  • Python | Print the first non-recurring element in a list October 26, 2020
  • Python | Print the most recurring element in a list October 26, 2020
  • Python | Find the cumulative sum of elements in a list October 26, 2020
  • Python | Check a character is present in a string or not October 26, 2020
  • Python | Check whether a string is palindrome or not October 26, 2020
  • Python | Find the missing number in the array of Ints October 26, 2020
  • Python | How would you delete duplicates in a list October 26, 2020
  • Python | Check whether an array is Monotonic or not October 26, 2020
  • Python | Check whether a number is prime or not October 26, 2020
  • Python | Print list of prime numbers up to a number October 26, 2020
  • Python | Print elements from odd positions in a list October 26, 2020
  • Python | Print positions of a string present in another string October 26, 2020
  • Python | How to sort an array in ascending order October 26, 2020
  • Python | How to reverse an array October 26, 2020
  • Python | Find un-common words from two strings October 26, 2020
  • Python | How to convert a string to a list October 26, 2020
  • Python | Find unique words from a string October 26, 2020
  • Python | Calculate average word length from a string October 26, 2020
  • Python | Find common words from two strings October 26, 2020
  • Python | Find the number of times a substring present in a string October 26, 2020
  • Python | Find maximum value from a list October 26, 2020
  • Python | How to find GCF of two numbers October 26, 2020
  • Python | How to find LCM of two numbers October 26, 2020
  • Python | How to convert a list to a string October 26, 2020
  • Python | Replace NONE by its previous NON None value October 26, 2020
  • Microsoft SQL Server 2019 | Features added to SQL Server on Linux September 26, 2018

Create a website or blog at WordPress.com

  • Follow Following
    • Improving my SQL BI Skills
    • Join 231 other followers
    • Already have a WordPress.com account? Log in now.
    • Improving my SQL BI Skills
    • Customize
    • Follow Following
    • Sign up
    • Log in
    • Report this content
    • View site in Reader
    • Manage subscriptions
    • Collapse this bar
 

Loading Comments...
 

You must be logged in to post a comment.