Performance when predicate is < Greater than ...

  • My table consists of 4 location IDs, each with a sensor reading value for each minute (approx) of the day, over a period of 1 month. (178,000 rows +/-)

    CREATE TABLE [CJ_LBSVTP].[IP21_Import_PowerTier](

    [locationID] [char](3) NOT NULL,

    [stamp] [datetime] NOT NULL,

    [value] [float] NULL

    )

    ... and my query has to create a start & end time from the above.

    So, if the table rows are thus ...

    Location Time Value

    1234 2013-03-01 00:01 98

    1234 2013-03-01 00:02 97

    The results should be ...

    Location StartTime EndTime

    1234 2013-03-01 00:01 2013-03-01 00:02

    My query code to do this is below, but it is taking a horrendously long time to execute.

    Have been playing with indexes for some time now and simply cannot get a decent time out of this one.

    Are there any 'tips' when doing such a query utilizing a '<' in the predicate ?

    Many Thanks

    --------- Query Code ---

    SELECT

    AA.LocationID

    , AA.stamp AS startStamp

    , MIN(BB.stamp) AS endStamp

    FROM

    myTable AS BB

    INNER JOIN

    myTable AS AA

    ON

    BB.LocationID = AA.LocationID AND

    BB.stamp > AA.stamp

    GROUP BY

    AA.LocationID

    , AA.stamp

  • What you have here is known by some as a triangular join. It is in fact horribly slow and inefficient. Take a look at this article that explains what you have going on here.

    http://www.sqlservercentral.com/articles/T-SQL/61539/[/url]

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • You might try using a derived table and getting TOP 1 with an ORDER BY to get the latest version instead of the > operator. Something like the code I have listed [/url]in this article. It might help.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Any chance you're on SQL Server 2012?

    SELECT LocationID,

    stamp AS startStamp,

    FIRST_VALUE(stamp) OVER(PARTITION BY LocationID

    ORDER BY stamp

    ROWS BETWEEN 1 FOLLOWING AND UNBOUNDED FOLLOWING) AS endStamp

    FROM myTable

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537

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

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