Wierd behavior of PARTITION BY Over clause with UNBOUNDED PRECEDING

  • having issue sorting this data last date for every minute of data, while last date for min is coming fine, cant make last bid qty using same method, first_value works though??

    Seems like a bug, any thoughts?

    Meanwhile using other methods to get this done.....

    declare @bidData table (activityDate datetime,BidQtyRaw bigint)

    insert into @bidData select 'Mar 28 2014 12:03:07:000PM',730384100

    insert into @bidData select 'Mar 28 2014 12:03:44:000PM',720528600

    insert into @bidData select 'Mar 28 2014 12:03:45:000PM',720528600

    insert into @bidData select 'Mar 28 2014 12:19:26:000PM',661768600

    insert into @bidData select 'Mar 28 2014 12:19:27:000PM',662768600

    insert into @bidData select 'Mar 28 2014 12:19:28:000PM',670718600

    insert into @bidData select 'Mar 28 2014 12:19:29:000PM',670718600

    insert into @bidData select 'Mar 28 2014 12:19:30:000PM',721218600

    insert into @bidData select 'Mar 28 2014 12:19:32:000PM',724218600

    insert into @bidData select 'Mar 28 2014 12:50:02:000PM',120538700

    insert into @bidData select 'Mar 28 2014 12:50:09:000PM',60678700

    select

    ActivityDate,datepart(minute,ActivityDate) ActivityMin,BidQtyRaw

    ,max(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows UNBOUNDED PRECEDING

    ) AS BidQtyMin

    ,first_value(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows UNBOUNDED PRECEDING

    ) AS BidQtyMinFirst

    ,max(ActivityDate) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows UNBOUNDED PRECEDING

    ) AS LastActivityDateMin

    from @bidData order by ActivityDate

    Prakash Heda
    Lead DBA Team - www.sqlfeatures.com
    Video sessions on Performance Tuning and SQL 2012 HA

  • Prakash Heda (3/29/2014)


    having issue sorting this data last date for every minute of data, while last date for min is coming fine, cant make last bid qty using same method, first_value works though??

    Seems like a bug, any thoughts?

    Meanwhile using other methods to get this done.....

    declare @bidData table (activityDate datetime,BidQtyRaw bigint)

    insert into @bidData select 'Mar 28 2014 12:03:07:000PM',730384100

    insert into @bidData select 'Mar 28 2014 12:03:44:000PM',720528600

    insert into @bidData select 'Mar 28 2014 12:03:45:000PM',720528600

    insert into @bidData select 'Mar 28 2014 12:19:26:000PM',661768600

    insert into @bidData select 'Mar 28 2014 12:19:27:000PM',662768600

    insert into @bidData select 'Mar 28 2014 12:19:28:000PM',670718600

    insert into @bidData select 'Mar 28 2014 12:19:29:000PM',670718600

    insert into @bidData select 'Mar 28 2014 12:19:30:000PM',721218600

    insert into @bidData select 'Mar 28 2014 12:19:32:000PM',724218600

    insert into @bidData select 'Mar 28 2014 12:50:02:000PM',120538700

    insert into @bidData select 'Mar 28 2014 12:50:09:000PM',60678700

    select

    ActivityDate,datepart(minute,ActivityDate) ActivityMin,BidQtyRaw

    ,max(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows UNBOUNDED PRECEDING

    ) AS BidQtyMin

    ,first_value(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows UNBOUNDED PRECEDING

    ) AS BidQtyMinFirst

    ,max(ActivityDate) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows UNBOUNDED PRECEDING

    ) AS LastActivityDateMin

    from @bidData order by ActivityDate

    The problem here is the default framing, when the clause is shortcut-ed, it defaults to the presets. For example, first_value has a default of rows between unbounded preceding and unbounded following while last_value has the default of rows between unbounded preceding and current row. Obviously for an ascending order, that is always going to return the current row.

    Compare the output of the previous query to this on;

    declare @bidData table (activityDate datetime,BidQtyRaw bigint)

    insert into @bidData select 'Mar 28 2014 12:03:07:000PM',730384100

    insert into @bidData select 'Mar 28 2014 12:03:44:000PM',720528600

    insert into @bidData select 'Mar 28 2014 12:03:45:000PM',720528600

    insert into @bidData select 'Mar 28 2014 12:19:26:000PM',661768600

    insert into @bidData select 'Mar 28 2014 12:19:27:000PM',662768600

    insert into @bidData select 'Mar 28 2014 12:19:28:000PM',670718600

    insert into @bidData select 'Mar 28 2014 12:19:29:000PM',670718600

    insert into @bidData select 'Mar 28 2014 12:19:30:000PM',721218600

    insert into @bidData select 'Mar 28 2014 12:19:32:000PM',724218600

    insert into @bidData select 'Mar 28 2014 12:50:02:000PM',120538700

    insert into @bidData select 'Mar 28 2014 12:50:09:000PM',60678700

    select

    ActivityDate,datepart(minute,ActivityDate) ActivityMin,BidQtyRaw

    ,max(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows BETWEEN UNBOUNDED PRECEDING

    AND UNBOUNDED FOLLOWING

    ) AS BidQtyMin

    ,first_value(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows BETWEEN UNBOUNDED PRECEDING

    AND UNBOUNDED FOLLOWING

    ) AS BidQtyMinFirst

    ,last_value(BidQtyRaw) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate asc

    Rows BETWEEN UNBOUNDED PRECEDING

    AND UNBOUNDED FOLLOWING

    ) AS BidQtyMinFirstL

    ,max(ActivityDate) OVER

    (

    PARTITION BY datepart(minute,ActivityDate)

    order by ActivityDate desc

    Rows BETWEEN UNBOUNDED PRECEDING

    AND UNBOUNDED FOLLOWING

    ) AS LastActivityDateMin

    from @bidData order by ActivityDate

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

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