Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Changed behavior or am I missing something? Expand / Collapse
Author
Message
Posted Thursday, May 1, 2014 12:39 PM This worked for the OP Answer marked as solution


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Friday, December 12, 2014 1:02 AM
Points: 823, Visits: 753
I'm not sure why Grant and others talk about update statistics, since everything is confined into a single script. There are no old statistics to update.

There is a new cardinality estimator, but I'm not sure that it matters for this case.

I ran the first script on SQL 2008 and after changing <= to >=, and it ran för two minutes and forty-five seconds. On SQL 2014, the script completed in 2:18, somewhat better.

I also tried to use Itzik Ben-Gans smart fn_nums:

CREATE FUNCTION dbo.fn_nums(@n AS bigint) RETURNS TABLE AS
RETURN
WITH
L0 AS(SELECT 1 AS c UNION ALL SELECT 1),
L1 AS(SELECT 1 AS c FROM L0 AS A, L0 AS B),
L2 AS(SELECT 1 AS c FROM L1 AS A, L1 AS B),
L3 AS(SELECT 1 AS c FROM L2 AS A, L2 AS B),
L4 AS(SELECT 1 AS c FROM L3 AS A, L3 AS B),
L5 AS(SELECT 1 AS c FROM L4 AS A, L4 AS B),
Nums AS(SELECT ROW_NUMBER() OVER(ORDER BY c) AS n FROM L5)
SELECT n AS Number FROM Nums WHERE n <= @n;

but I gave up when my query had not completed in four minutes.

I think it is better to have a table of numbers. While sometimes the optimizer can use these exploding CTEs correctly, it has little clue of what is going on and it may come up with complete crazy plans.


Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Post #1566823
Posted Sunday, May 4, 2014 2:32 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 2:08 PM
Points: 2,532, Visits: 7,077
Firstly, thank you all for looking into this. It was me after all missing something rather obvious, maybe too obvious. The CTE in the code generates a sequence of 10^8 entries which crosses the threshold of noticeable generation time (see table).

+------------+--------+---------+
| Row count | CPU ms | Elapsed |
+------------+--------+---------+
| 100 | 0 | 0 |
| 1000 | 0 | 0 |
| 10000 | 0 | 1 |
| 100000 | 16 | 17 |
| 1000000 | 217 | 155 |
| 10000000 | 1981 | 1566 |
| 100000000 | 20313 | 15955 |
| 1000000000 | 194144 | 153251 |
+------------+--------+---------+


Testing on 2008 to 2014 produced similar performance and almost identical execution plans with only a slight difference in cost distribution. Erland was spot on, all of the plans exhausted the CTE number generation.

I believe that Itzik Ben-Gans smart fn_nums is more geared towards populating number tables than for inline usage such as this. He has another version which includes a TOP/OOF clause. In fact, without a TOP/OOF clause, all tests had the same problem, regardless of the maximum number or the presence of a where / filtering clause outside the CTE.

Fixing this in the code was simply a case of changing the second CTE.


;WITH NX(N) AS (SELECT N FROM (VALUES (1),(1),(1),(1),(1),(1),(1),(1),(1),(1)) AS X(N))
SELECT
MT.MYTEMP_ID
,NM.N
,SUBSTRING(MT.MYTEMP_STR,NM.N,1) AS STR_PART
FROM #MYTEMP MT
CROSS APPLY
(
/* Tally moved here for using the len() to limit the rowcount */
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 1)) AS N
FROM NX N1,NX N2,NX N3 ,NX N4,NX N5,NX N6,NX N7,NX N8,NX N9 -- (10^9)
ORDER BY 1 OFFSET 0 ROWS FETCH FIRST (LEN(MT.MYTEMP_STR)) ROWS ONLY
) AS NM;

Post #1567319
Posted Sunday, May 4, 2014 3:25 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 2:09 AM
Points: 1,816, Visits: 5,911
It's interesting that you used fetch first N instead of TOP(N).

Was there a performance improvement or just personal preference?


MM


  • MMGrid Addin
  • MMNose Addin


  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • Post #1567323
    Posted Sunday, May 4, 2014 3:46 AM
    SSCrazy

    SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

    Group: General Forum Members
    Last Login: Today @ 2:08 PM
    Points: 2,532, Visits: 7,077
    mister.magoo (5/4/2014)
    It's interesting that you used fetch first N instead of TOP(N).

    Was there a performance improvement or just personal preference?



    It is more of a preference, kind of a reminder when I'm working on 2012/2014
    The server introduces the same TOP operator for both, haven't seen any difference in performance.
    Post #1567324
    Posted Monday, May 5, 2014 7:31 AM


    SSCommitted

    SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

    Group: General Forum Members
    Last Login: Today @ 1:23 PM
    Points: 1,792, Visits: 5,041
    What method did you use to port the database?

    Remember to use a schema comparison tool to insure things like indexes, table options, statistics, constraints, plan guides, etc. are all the same before attempting a baseline comparison. Also the method used to copy table data to the new instance (if that's the case) could have resulted in fragmentation.
    Post #1567501
    Posted Monday, May 5, 2014 10:48 AM
    SSCrazy

    SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

    Group: General Forum Members
    Last Login: Today @ 2:08 PM
    Points: 2,532, Visits: 7,077
    Eric M Russell (5/5/2014)
    What method did you use to port the database?

    Remember to use a schema comparison tool to insure things like indexes, table options, statistics, constraints, plan guides, etc. are all the same before attempting a baseline comparison. Also the method used to copy table data to the new instance (if that's the case) could have resulted in fragmentation.


    This is a dev system and I just ran an upgrade from 2012 to 2014 as the SSD is getting slightly cramped. Part of the exercise was to test the effects of the upgrade on the surrounding systems, even kept the instance name the same. So far everything is jolly, figured out that it was me missing something, not any changes in the behaviour


    Post #1567623
    « Prev Topic | Next Topic »

    Add to briefcase ««12

    Permissions Expand / Collapse