Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Wierd behavior of PARTITION BY Over clause with UNBOUNDED PRECEDING


Wierd behavior of PARTITION BY Over clause with UNBOUNDED PRECEDING

Author
Message
Prakash Heda
Prakash Heda
Old Hand
Old Hand (380 reputation)Old Hand (380 reputation)Old Hand (380 reputation)Old Hand (380 reputation)Old Hand (380 reputation)Old Hand (380 reputation)Old Hand (380 reputation)Old Hand (380 reputation)

Group: General Forum Members
Points: 380 Visits: 416
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
      Wink AS BidQtyMin
   ,first_value(BidQtyRaw) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate desc
      Rows UNBOUNDED PRECEDING
      Wink AS BidQtyMinFirst
   ,max(ActivityDate) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate desc
      Rows UNBOUNDED PRECEDING
      Wink AS LastActivityDateMin
from @bidData order by ActivityDate




Prakash Heda
Lead DBA Team - www.sqlfeatures.com
Video sessions on Performance Tuning and SQL 2012 HA
Eirikur Eiriksson
Eirikur Eiriksson
SSCertifiable
SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)

Group: General Forum Members
Points: 6693 Visits: 17687
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
      Wink AS BidQtyMin
   ,first_value(BidQtyRaw) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate desc
      Rows UNBOUNDED PRECEDING
      Wink AS BidQtyMinFirst
   ,max(ActivityDate) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate desc
      Rows UNBOUNDED PRECEDING
      Wink 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
      Wink AS BidQtyMin
   ,first_value(BidQtyRaw) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate desc
      Rows BETWEEN UNBOUNDED PRECEDING
       AND UNBOUNDED FOLLOWING
      Wink AS BidQtyMinFirst
   ,last_value(BidQtyRaw) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate asc
      Rows BETWEEN UNBOUNDED PRECEDING
       AND UNBOUNDED FOLLOWING
      Wink AS BidQtyMinFirstL
   ,max(ActivityDate) OVER
      (
      PARTITION BY datepart(minute,ActivityDate)
      order by ActivityDate desc
      Rows BETWEEN UNBOUNDED PRECEDING
       AND UNBOUNDED FOLLOWING
      Wink AS LastActivityDateMin
from @bidData order by ActivityDate


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search