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


Show data based on MAX Action date - end of the month


Show data based on MAX Action date - end of the month

Author
Message
jaggy99
jaggy99
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1062 Visits: 65
Hi,

I have the below query and like to show only the values highlighted in yellow in 2018-01-31. The previous months are fine. We need each tenant code to appear once every month based on the max action date






Declare @diary TABLE ([Diary Reference] int, [Tenant Code] varchar(7), [Category] varchar(4), [Action Date] date, [Follow on Date] date, [Action Code] varchar(4), [Follow on Ind] varchar(5), [Created Date] date, [Created Time] varchar(7) )

INSERT INTO @diary ([Diary Reference],[Tenant Code], [Category], [Action Date], [Follow on Date], [Action Code], [Follow on Ind], [Created Date], [Created Time])
VALUES
(236774,'42441', 'RARP', '2017-02-06', '2017-04-26', 'MARP', 'Taken', '2018-01-26', '19:51'),
(236773,'42441', 'RARP', '2017-07-17', '2017-08-15', 'RPSB', 'Taken', '2018-01-26', '19:49'),
(234006,'42441', 'RARP', '2017-12-22', '2018-01-09', 'RPSO', 'Taken', '2017-12-22', '8:41'),
(235852,'42441', 'RARP', '2018-01-10', NULL, 'RSOA', 'None', '2018-01-10', '11:19'),
(236772, '54482', 'RARP', '2017-10-26', '2018-01-26', 'RPSO', 'Taken', '2018-01-26', '19:20'),
(235174, 37702, 'RARP', '2018-01-05', '2018-01-05', 'RPSO', 'Taken', '2018-01-05', '12:09'),
(235175, 37702, 'RARP', '2018-01-05', '2018-01-08', 'RPSB', 'Taken', '2018-01-05', '12:11'),
(235784, 37702, 'RARP', '2018-01-09', NULL, 'RPSO', 'None', '2018-01-09', '16:35'),
(236775, 37702, 'RARP', '2017-11-16', '2018-01-10', 'RPSB', 'Taken', '2018-01-26', '22:42')

;with dates(Month_End) as (select cast('2014-01-01' as datetime)-1 as datetime union all
select DATEADD(month, 1, Month_End+1)-1
from dates where Month_End < GETDATE()),Months As
(select DateAdd(month, -1, DateAdd(day, 1, Month_End)) As Month_Start,Month_End,ts.[Diary Reference],ts.[Tenant Code],ts.Category,ts.[Action Code],ts.[Action Date],ts.[Follow on Date],ts.[Created Date]

FROM @diary ts join dates d ON d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0)))

Select Month_Start,Month_End,months.[Tenant Code],[Diary Reference],Category,months.[Action Date],[Follow on Date],[Action Code]

From Months
order by Month_End, [Tenant Code], [Action Date]






Thanks
Sean Pearce
Sean Pearce
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14042 Visits: 3530
You can simply use the ROW_NUMBER function in your CTE, like this:

Declare @diary TABLE  ([Diary Reference] int, [Tenant Code] varchar(7), [Category] varchar(4), [Action Date] date, [Follow on Date] date, [Action Code] varchar(4), [Follow on Ind] varchar(5), [Created Date] date, [Created Time] varchar(7)  ) 

INSERT INTO @diary ([Diary Reference],[Tenant Code], [Category], [Action Date], [Follow on Date], [Action Code], [Follow on Ind], [Created Date], [Created Time])
VALUES
(236774,'42441', 'RARP', '2017-02-06', '2017-04-26', 'MARP', 'Taken', '2018-01-26', '19:51'),
(236773,'42441', 'RARP', '2017-07-17', '2017-08-15', 'RPSB', 'Taken', '2018-01-26', '19:49'),
(234006,'42441', 'RARP', '2017-12-22', '2018-01-09', 'RPSO', 'Taken', '2017-12-22', '8:41'),
(235852,'42441', 'RARP', '2018-01-10', NULL, 'RSOA', 'None', '2018-01-10', '11:19'),
(236772, '54482', 'RARP', '2017-10-26', '2018-01-26', 'RPSO', 'Taken', '2018-01-26', '19:20'),
(235174, 37702, 'RARP', '2018-01-05', '2018-01-05', 'RPSO', 'Taken', '2018-01-05', '12:09'),
(235175, 37702, 'RARP', '2018-01-05', '2018-01-08', 'RPSB', 'Taken', '2018-01-05', '12:11'),
(235784, 37702, 'RARP', '2018-01-09', NULL, 'RPSO', 'None', '2018-01-09', '16:35'),
(236775, 37702, 'RARP', '2017-11-16', '2018-01-10', 'RPSB', 'Taken', '2018-01-26', '22:42');

with
dates(Month_End) as (
select cast('2014-01-01' as datetime)-1 as datetime
union all
select DATEADD(month, 1, Month_End+1)-1
from dates where Month_End < GETDATE()),
Months As (
select
DateAdd(month, -1, DateAdd(day, 1, Month_End)) As Month_Start,
Month_End,
ts.[Diary Reference],
ts.[Tenant Code],
ts.Category,
ts.[Action Code],
ts.[Action Date],
ts.[Follow on Date],
ts.[Created Date],
ROW_NUMBER() OVER (PARTITION BY ts.[Tenant Code], DateAdd(month, -1, DateAdd(day, 1, Month_End)) ORDER BY ts.[Action Date] DESC, ts.[Follow on Date] DESC) AS RowNo
FROM
@diary ts
join
dates d ON d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0)))

Select Month_Start,Month_End,months.[Tenant Code],[Diary Reference],Category,months.[Action Date],[Follow on Date],[Action Code]
From Months
where RowNo = 1
order by Month_End, [Tenant Code], [Action Date]





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
jaggy99
jaggy99
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1062 Visits: 65
Thanks Sean that worked. What about the below approach?



;with dates(Month_End) as (select cast('2014-01-01' as datetime)-1 as datetime union all select DATEADD(month, 1, Month_End+1)-1
from dates where Month_End < GETDATE()),Months As
(select DateAdd(month, -1, DateAdd(day, 1, Month_End)) As Month_Start,Month_End,ts.[Diary Reference],ts.[Tenant Code],ts.Category,ts.[Action Code],ts.[Action Date],ts.[Follow on Date],ts.[Created Date]
FROM @diary ts join dates d ON d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0)))

SELECT * FROM (Select Month_End,months.[Tenant Code],MAX(months.[Action Date]) As [Max Action Date]
From Months Group BY Month_End,months.[Tenant Code]) AS Der order by Month_End, [Tenant Code]






jaggy99
jaggy99
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1062 Visits: 65
Sean Pearce - Monday, January 29, 2018 11:38 PM
You can simply use the ROW_NUMBER function in your CTE, like this:

Declare @diary TABLE  ([Diary Reference] int, [Tenant Code] varchar(7), [Category] varchar(4), [Action Date] date, [Follow on Date] date, [Action Code] varchar(4), [Follow on Ind] varchar(5), [Created Date] date, [Created Time] varchar(7)  ) 

INSERT INTO @diary ([Diary Reference],[Tenant Code], [Category], [Action Date], [Follow on Date], [Action Code], [Follow on Ind], [Created Date], [Created Time])
VALUES
(236774,'42441', 'RARP', '2017-02-06', '2017-04-26', 'MARP', 'Taken', '2018-01-26', '19:51'),
(236773,'42441', 'RARP', '2017-07-17', '2017-08-15', 'RPSB', 'Taken', '2018-01-26', '19:49'),
(234006,'42441', 'RARP', '2017-12-22', '2018-01-09', 'RPSO', 'Taken', '2017-12-22', '8:41'),
(235852,'42441', 'RARP', '2018-01-10', NULL, 'RSOA', 'None', '2018-01-10', '11:19'),
(236772, '54482', 'RARP', '2017-10-26', '2018-01-26', 'RPSO', 'Taken', '2018-01-26', '19:20'),
(235174, 37702, 'RARP', '2018-01-05', '2018-01-05', 'RPSO', 'Taken', '2018-01-05', '12:09'),
(235175, 37702, 'RARP', '2018-01-05', '2018-01-08', 'RPSB', 'Taken', '2018-01-05', '12:11'),
(235784, 37702, 'RARP', '2018-01-09', NULL, 'RPSO', 'None', '2018-01-09', '16:35'),
(236775, 37702, 'RARP', '2017-11-16', '2018-01-10', 'RPSB', 'Taken', '2018-01-26', '22:42');

with
dates(Month_End) as (
select cast('2014-01-01' as datetime)-1 as datetime
union all
select DATEADD(month, 1, Month_End+1)-1
from dates where Month_End < GETDATE()),
Months As (
select
DateAdd(month, -1, DateAdd(day, 1, Month_End)) As Month_Start,
Month_End,
ts.[Diary Reference],
ts.[Tenant Code],
ts.Category,
ts.[Action Code],
ts.[Action Date],
ts.[Follow on Date],
ts.[Created Date],
ROW_NUMBER() OVER (PARTITION BY ts.[Tenant Code], DateAdd(month, -1, DateAdd(day, 1, Month_End)) ORDER BY ts.[Action Date] DESC, ts.[Follow on Date] DESC) AS RowNo
FROM
@diary ts
join
dates d ON d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0)))

Select Month_Start,Month_End,months.[Tenant Code],[Diary Reference],Category,months.[Action Date],[Follow on Date],[Action Code]
From Months
where RowNo = 1
order by Month_End, [Tenant Code], [Action Date]



When i run the query in production for tenant code 37702, i get one record


drew.allen
drew.allen
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60452 Visits: 15929
jaggy99 - Tuesday, January 30, 2018 12:17 AM
Thanks Sean that worked. What about the below approach?



;with dates(Month_End) as (select cast('2014-01-01' as datetime)-1 as datetime union all select DATEADD(month, 1, Month_End+1)-1
from dates where Month_End < GETDATE()),Months As
(select DateAdd(month, -1, DateAdd(day, 1, Month_End)) As Month_Start,Month_End,ts.[Diary Reference],ts.[Tenant Code],ts.Category,ts.[Action Code],ts.[Action Date],ts.[Follow on Date],ts.[Created Date]
FROM @diary ts join dates d ON d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0)))

SELECT * FROM (Select Month_End,months.[Tenant Code],MAX(months.[Action Date]) As [Max Action Date]
From Months Group BY Month_End,months.[Tenant Code]) AS Der order by Month_End, [Tenant Code]







This approach is horrible.
1) Do you have something against carriage returns? Most people try to keep the columns lengths less than 80 characters, because that makes it easier to read. You have lines that are over 200 characters.
2) You use an rCTE to calculate the dates which is horribly inefficient. You should use a tally (numbers) table instead.
/*  I've used an ad hoc tally table here, but Itzik Ben Gan has a very efficient tally table function  */;
WITH Base(n) AS
(
SELECT n
FROM (VALUES(0), (0), (0), (0), (0), (0), (0), (0), (0), (0) ) b(n)
)
, Tally(n) AS
(
SELECT TOP(DATEDIFF(MONTH, '2013-12-31', GETDATE()) + 1) ROW_NUMBER() OVER(ORDER BY @@VERSION) - 1
FROM Base AS a
CROSS JOIN Base AS b
CROSS JOIN Base AS c
/* Add additional CROSS JOINS as necessary */
)
SELECT DATEADD(MONTH, n, '2013-12-31')
FROM Tally

3) You're using closed date intervals (b BETWEEN a AND c) instead of half-closed date intervals ( a <= b and b < c). The primary issue is that is forces you to use complex calculations that are no longer SARGable
d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0))
/* rewritten using half-closed intervals. */
[Action Date] <= d.Month_End AND d.Month_End < [Follow on Date]

Another issue is that you may miss if you don't use the right precision or double count records if you forget to adjust.
4) You mix derived tables and CTEs. For most purposes, derived tables and CTEs are functionally equivalent, so it makes it easier to understand if you stick to one or the other. The one exception is that derived tables do not support recursion.
5) You have a superfluous derived table. You have a derived table that does nothing that cannot be done in the main query. Since derived tables make it harder to understand a query, you should avoid them when possible.
/*  The following */
SELECT *
FROM
(
Select
Month_End,
months.[Tenant Code],
MAX(months.[Action Date]) As [Max Action Date]
From Months
Group BY Month_End, months.[Tenant Code]
) AS Der order by Month_End, [Tenant Code]
;
/* can be rewritten as follows without changing functionality */
SELECT
Month_End,
months.[Tenant Code],
MAX(months.[Action Date]) As [Max Action Date]
FROM Months
Group BY Month_End, months.[Tenant Code]
order by Month_End, [Tenant Code]
;


Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
jaggy99
jaggy99
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1062 Visits: 65
drew.allen - Tuesday, January 30, 2018 10:07 AM
jaggy99 - Tuesday, January 30, 2018 12:17 AM
Thanks Sean that worked. What about the below approach?



;with dates(Month_End) as (select cast('2014-01-01' as datetime)-1 as datetime union all select DATEADD(month, 1, Month_End+1)-1
from dates where Month_End < GETDATE()),Months As
(select DateAdd(month, -1, DateAdd(day, 1, Month_End)) As Month_Start,Month_End,ts.[Diary Reference],ts.[Tenant Code],ts.Category,ts.[Action Code],ts.[Action Date],ts.[Follow on Date],ts.[Created Date]
FROM @diary ts join dates d ON d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0)))

SELECT * FROM (Select Month_End,months.[Tenant Code],MAX(months.[Action Date]) As [Max Action Date]
From Months Group BY Month_End,months.[Tenant Code]) AS Der order by Month_End, [Tenant Code]







This approach is horrible.
1) Do you have something against carriage returns? Most people try to keep the columns lengths less than 80 characters, because that makes it easier to read. You have lines that are over 200 characters.
2) You use an rCTE to calculate the dates which is horribly inefficient. You should use a tally (numbers) table instead.
/*  I've used an ad hoc tally table here, but Itzik Ben Gan has a very efficient tally table function  */;
WITH Base(n) AS
(
SELECT n
FROM (VALUES(0), (0), (0), (0), (0), (0), (0), (0), (0), (0) ) b(n)
)
, Tally(n) AS
(
SELECT TOP(DATEDIFF(MONTH, '2013-12-31', GETDATE()) + 1) ROW_NUMBER() OVER(ORDER BY @@VERSION) - 1
FROM Base AS a
CROSS JOIN Base AS b
CROSS JOIN Base AS c
/* Add additional CROSS JOINS as necessary */
)
SELECT DATEADD(MONTH, n, '2013-12-31')
FROM Tally

3) You're using closed date intervals (b BETWEEN a AND c) instead of half-closed date intervals ( a <= b and b < c). The primary issue is that is forces you to use complex calculations that are no longer SARGable
d.Month_End Between [Action Date] and DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,isnull(ts.[Follow on Date], GETDATE()))+1,0))
/* rewritten using half-closed intervals. */
[Action Date] <= d.Month_End AND d.Month_End < [Follow on Date]

Another issue is that you may miss if you don't use the right precision or double count records if you forget to adjust.
4) You mix derived tables and CTEs. For most purposes, derived tables and CTEs are functionally equivalent, so it makes it easier to understand if you stick to one or the other. The one exception is that derived tables do not support recursion.
5) You have a superfluous derived table. You have a derived table that does nothing that cannot be done in the main query. Since derived tables make it harder to understand a query, you should avoid them when possible.
/*  The following */
SELECT *
FROM
(
Select
Month_End,
months.[Tenant Code],
MAX(months.[Action Date]) As [Max Action Date]
From Months
Group BY Month_End, months.[Tenant Code]
) AS Der order by Month_End, [Tenant Code]
;
/* can be rewritten as follows without changing functionality */
SELECT
Month_End,
months.[Tenant Code],
MAX(months.[Action Date]) As [Max Action Date]
FROM Months
Group BY Month_End, months.[Tenant Code]
order by Month_End, [Tenant Code]
;


Drew


Hi Drew,

Could you please combine the query.

Thanks
Jag
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