Which Query has better statistics ?

  • Queries

    set statistics time on

    SELECT [SalesOrderID], *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 750

    UNION

    SELECT [SalesOrderID], *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 953

    SELECT SalesOrderID, *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 750 OR ProductID = 953

    Statistics

    (704 row(s) affected)

    Table 'SalesOrderDetail'. Scan count 2, logical reads 2179, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 16 ms, elapsed time = 364 ms.

    (704 row(s) affected)

    Table 'SalesOrderDetail'. Scan count 1, logical reads 1240, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 109 ms, elapsed time = 606 ms.

    i have attached the exec plans too

    -------Bhuvnesh----------
    I work only to learn Sql Server...though my company pays me for getting their stuff done;-)

  • Don't run queries with exec plans on to take time stats. Also make sure you run more than once and ignore the first run (caching)

    On a larger data volume, but with the same form of exec plans (I've padded AW out to help test performance issues):

    (5632 row(s) affected)

    Table 'SalesOrderDetail'. Scan count 10, logical reads 19068, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 203 ms, elapsed time = 331 ms.

    (5632 row(s) affected)

    Table 'SalesOrderDetail'. Scan count 5, logical reads 10564, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 250 ms, elapsed time = 279 ms.

    btw, the reason there's a plan difference at all here is because the rows in total are above the tipping point (where seeks + key lookups are considered efficient) but the rows in each branch of the union is below that.

    Hence, the union does seeks plus the number of key lookups that the optimiser considered to be inefficient when the query was a single plan. Have many more or many fewer rows, and you won't see the same effect.

    Basically, the writer of that blog post either coincidentally hit on row counts that showed very different plans, or he went looking for rowcounts that showed very different plans, he didn't show or discuss the general case

    Many fewer rows:

    SELECT [SalesOrderID], *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 897

    UNION

    SELECT [SalesOrderID], *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 942

    SELECT SalesOrderID, *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 897 OR ProductID = 942

    Both the OR and the Union do seeks and key lookups, because the row count of both the combined query and the two unioned queries are low enough that key lookups are acceptable.

    Union

    Table 'SalesOrderDetail'. Scan count 2, logical reads 193, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    (56 row(s) affected)

    OR

    Table 'SalesOrderDetail'. Scan count 2, logical reads 188, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 0 ms.

    Many more rows:

    SELECT [SalesOrderID], *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 712

    UNION

    SELECT [SalesOrderID], *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 870

    SELECT SalesOrderID, *

    FROM Sales.SalesOrderDetail

    WHERE ProductID = 712 OR ProductID = 870

    Both the OR and the Union do table scans. One complete table scan for the query with the OR. Two complete table scans for the query with the union.

    (64560 row(s) affected)

    Table 'SalesOrderDetail'. Scan count 10, logical reads 21128, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 469 ms, elapsed time = 970 ms.

    (64560 row(s) affected)

    Table 'SalesOrderDetail'. Scan count 5, logical reads 10564, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 343 ms, elapsed time = 825 ms.

    So in summary, except for a special case where the total number of rows is above the tipping point (the point at which SQL switches from seeks and key lookups to table scans) and the number of rows in each unioned query is below, and we're using non-covering indexes, the union is either the same or far less efficient.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Thanks gail for explanation..

    -------Bhuvnesh----------
    I work only to learn Sql Server...though my company pays me for getting their stuff done;-)

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply