SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


inconsistent record set using ROW_NUMBER() function


inconsistent record set using ROW_NUMBER() function

Author
Message
dbsiva-707412
dbsiva-707412
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 172
Getting inconsistent record set While doing paging using ROW_NUMBER() function. Each time of execution i am getting different 100th record.after going throw the actual records, i found order by clause column fetches random records when it has same records in last record in current page and first record in next page.Below are my sample data.

100 17789 Ramesh Patel Queens 2007-08-31 17:08:03.650 242951 Placement 2006-08-01 00:00:00.000 (ACC) McDonalds
101 42642 John Kim Queens 2007-09-10 18:05:18.977 244446 Placement 2007-06-01 00:00:00.000 (ACC) McDonalds
102 250977 Roget Sachin Queens 2007-08-29 16:38:04.557 242200 Placement 2007-04-24 00:00:00.000 (ACC) McDonalds
103 277414 Fed Khan Queens 2008-04-21 18:17:59.930 296856 Placement 2007-12-02 00:00:00.000 (ACC) McDonalds
104 285158 Rodger mo Queens 2008-06-26 14:31:10.970 315119 Placement 2008-01-04 00:00:00.000 (ACC) McDONALDS
105 158322 Andy Thomas Queens 2008-04-11 16:20:15.540 294820 Placement 2007-11-19 00:00:00.000 (ACC) McDonalds

Since order by column has same value as "(ACC) McDonalds" and displaying 100 records per page,so each time of 100th record is coming randomly from those 6 records.

Query:-

SELECT RowNum, PeopleID, FIRSTNAME,LASTNAME,Center ,DateCreated ,WorkHistID,Source,JobStartDate,Employer,Position,WageHour
FROM
(SELECT P.PeopleID, P.FIRSTNAME,P.LASTNAME
,C.CenterNameShort as Center
,WH.DATECREATED as DateCreated ,WH.WorkHistID,WH.Source, WH.JobStartDate,O.ORGANIZATIONNAME AS Employer,
WH.JobTitle as Position,WH.WAGETOTALCOMPENSATION as WageHour
,ROW_NUMBER() OVER (ORDER BY O.ORGANIZATIONNAME ASC) as RowNum
from PEOPLE P
INNER JOIN Workhist WH ON(P.PeopleID = WH.PeopleID)
INNER JOIN CenterMaster C ON(WH.CenterID =C.CenterID)
INNER JOIN OrganizationMaster O ON(WH.OrganizationID=O.OrganizationID)
where C.CenternameShort= @CenterID
and WH.datecreated >= @StartDate AND WH.datecreated < @EndDate + 1 AND WH.Source= @Source
) AS Page
WHERE Page.RowNum BETWEEN (@PageIndex * @PageSize+ 1) and ((@PageIndex + 1) * @PageSize)



Below are Sample Records:-

100 17789 Ramesh Patel Queens 2007-08-31 17:08:03.650 242951 Placement 2006-08-01 00:00:00.000 (ACC) McDonalds
101 42642 John Kim Queens 2007-09-10 18:05:18.977 244446 Placement 2007-06-01 00:00:00.000 (ACC) McDonalds
102 250977 Roget Sachin Queens 2007-08-29 16:38:04.557 242200 Placement 2007-04-24 00:00:00.000 (ACC) McDonalds
103 277414 Fed Khan Queens 2008-04-21 18:17:59.930 296856 Placement 2007-12-02 00:00:00.000 (ACC) McDonalds
104 285158 Rodger mo Queens 2008-06-26 14:31:10.970 315119 Placement 2008-01-04 00:00:00.000 (ACC) McDONALDS
105 158322 Andy Thomas Queens 2008-04-11 16:20:15.540 294820 Placement 2007-11-19 00:00:00.000 (ACC) McDonalds

Getting inconsistent record set While doing paging using ROW_NUMBER() function.

Is there any issue in my query or there is a issue in the behaviour of ROW_NUMBER() function???

Any help or suggestion will be appreciated.

Thanks
Lempster
Lempster
SSCertifiable
SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)

Group: General Forum Members
Points: 5079 Visits: 1657
Hello,

You've probably long since found the answer to your question given that your post is almost 1 year old, but it's because the ROW_NUMBER() functions is non-deterministic unless you provide a 'tie-breaker' to make the values unique. In your example you could use:
ROW_NUMBER() OVER (ORDER BY O.ORGANIZATIONNAME, P.PeopleID) AS Rownum



Regards
Lempster
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