July 17, 2015 at 11:18 am
adding quick consumable info for others to run with the ball:
;WITH TableA([date],[ID])
AS
(
SELECT '2012-09-21','1' UNION ALL
SELECT '2012-09-28','1' UNION ALL
SELECT '2012-10-05','1' UNION ALL
SELECT '2012-10-12','1' UNION ALL
SELECT '2012-10-19','1' UNION ALL
SELECT '2012-10-26','1' UNION ALL
SELECT '2012-11-02','1' UNION ALL
SELECT '2012-11-09','1' UNION ALL
SELECT '2013-01-18','1' UNION ALL
SELECT '2013-01-25','1' UNION ALL
SELECT '2013-02-01','1'
),
TableB([date],[ID],[eps])
AS
(
SELECT '2012-03-31','1','1.3' UNION ALL
SELECT '2012-06-30','1','0.8' UNION ALL
SELECT '2012-09-30','1','0.5' UNION ALL
SELECT '2012-12-31','1','2.5'
)
SELECT * FROM TableA
INNER JOIN TableB
Lowell
July 17, 2015 at 11:34 am
Something like this? (I dropped the leading ; from the CTE as it is not needed.)
WITH TableA([date],[ID])
AS
(
SELECT '2012-09-21','1' UNION ALL
SELECT '2012-09-28','1' UNION ALL
SELECT '2012-10-05','1' UNION ALL
SELECT '2012-10-12','1' UNION ALL
SELECT '2012-10-19','1' UNION ALL
SELECT '2012-10-26','1' UNION ALL
SELECT '2012-11-02','1' UNION ALL
SELECT '2012-11-09','1' UNION ALL
SELECT '2013-01-18','1' UNION ALL
SELECT '2013-01-25','1' UNION ALL
SELECT '2013-02-01','1'
),
TableB([date],[ID],[eps])
AS
(
SELECT '2012-03-31','1','1.3' UNION ALL
SELECT '2012-06-30','1','0.8' UNION ALL
SELECT '2012-09-30','1','0.5' UNION ALL
SELECT '2012-12-31','1','2.5'
)
select
*
from
TableA a
cross apply (select top (1) * from TableB b where a.ID = b.ID and b.[date] <= a.[date] order by b.[date] desc)ca;
July 17, 2015 at 11:45 am
If you're using natural quarters, you might be able to use something like this:
WITH TableA([date],[ID])
AS
(
SELECT '2012-09-21','1' UNION ALL
SELECT '2012-09-28','1' UNION ALL
SELECT '2012-10-05','1' UNION ALL
SELECT '2012-10-12','1' UNION ALL
SELECT '2012-10-19','1' UNION ALL
SELECT '2012-10-26','1' UNION ALL
SELECT '2012-11-02','1' UNION ALL
SELECT '2012-11-09','1' UNION ALL
SELECT '2013-01-18','1' UNION ALL
SELECT '2013-01-25','1' UNION ALL
SELECT '2013-02-01','1'
),
TableB([date],[ID],[eps])
AS
(
SELECT '2012-03-31','1','1.3' UNION ALL
SELECT '2012-06-30','1','0.8' UNION ALL
SELECT '2012-09-30','1','0.5' UNION ALL
SELECT '2012-12-31','1','2.5'
)
SELECT a.date,
a.ID,
b.eps
FROM TableA a
INNER JOIN TableB b ON a.ID = b.ID
AND a.date >= b.date
AND a.date < DATEADD( DD, - DATEPART( dd, DATEADD( MM, 4, b.date)), DATEADD( MM, 4, b.date))
July 17, 2015 at 12:10 pm
Thank you for all of your help. I will try it.
Thank you.
Viewing 4 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply