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


using CTE how we can achive this. please help me


using CTE how we can achive this. please help me

Author
Message
vemula.narayanan
vemula.narayanan
Old Hand
Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)

Group: General Forum Members
Points: 335 Visits: 44
Declare @Input Table(EmpID VARCHAR(50), from_value int, to_value int);
Insert @Input(EmpID, from_value,to_value) Values
('E1', 1, 4),
('E1', 5,null),
('E1', 7, Null);

Select * from @Input


Need out put like

EmpID from_value to_value
E1 1 4
E1 5 6
E1 7 NULL


Next from value of the employee is 7 so 7-1 =6. this 6 value will be the to_value of previous record
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)

Group: General Forum Members
Points: 115091 Visits: 21438
vemula.narayanan - Friday, December 29, 2017 1:04 AM
Declare @Input Table(EmpID VARCHAR(50), from_value int, to_value int);
Insert @Input(EmpID, from_value,to_value) Values
('E1', 1, 4),
('E1', 5,null),
('E1', 7, Null);

Select * from @Input


Need out put like

EmpID from_value to_value
E1 1 4
E1 5 6
E1 7 NULL


Next from value of the employee is 7 so 7-1 =6. this 6 value will be the to_value of previous record

Two suggestions, one for SQL Server 2008 and earlier, the other for 2012 and later
Cool

Declare @Input Table(EmpID VARCHAR(50), from_value int, to_value int);
Insert @Input(EmpID, from_value,to_value) Values
('E1', 1, 4),
('E1', 5,null),
('E1', 7, Null);

--SQL SERVER 2008 AND EARLIER
;WITH BASE_DATA AS
(
SELECT
ROW_NUMBER() OVER
(
PARTITION BY IP.EmpID
ORDER BY IP.from_value ASC
) AS EMP_RID
,IP.EmpID
,IP.from_value
,IP.to_value
FROM @Input IP
)
SELECT
BD.EmpID
,BD.from_value
,ISNULL(BD.to_value,(B2.from_value - 1)) AS to_value
FROM BASE_DATA BD
LEFT OUTER JOIN BASE_DATA B2
ON BD.EMP_RID = (B2.EMP_RID - 1)
AND BD.EmpID = B2.EmpID;

-- SQL SERVER 2012 AND LATER
SELECT
IP.EmpID
,IP.from_value
,ISNULL( IP.to_value
,LEAD(IP.from_value,1,NULL) OVER
(
PARTITION BY IP.EmpID
ORDER BY IP.from_value
) - 1
) AS to_value
FROM @Input IP;

vemula.narayanan
vemula.narayanan
Old Hand
Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)Old Hand (335 reputation)

Group: General Forum Members
Points: 335 Visits: 44
Thanks a lot EirikurSmile
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)SSC Guru (115K reputation)

Group: General Forum Members
Points: 115091 Visits: 21438
vemula.narayanan - Friday, December 29, 2017 1:26 AM
Thanks a lot EirikurSmile

You are welcome!
Cool

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