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


Getting Max date from rows


Getting Max date from rows

Author
Message
JaybeeSQL
JaybeeSQL
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2619 Visits: 986
Hi all,
I'm trying to get the latest date for every distinct value in a column:
CREATE TABLE [dbo].[Ledger](
[ID] [int] NOT NULL,
[ProfileId] [int] NULL,
[Date] [datetime] NULL,
[Time] [datetime] NULL

) ON [PRIMARY]
GO
--Sample Data
--Select Top 8 ProfileId, Date, Paid
--From Ledger As L
1657 Nov 10 2009 12:00AM 150.00
1657 May 8 2009 12:00AM 150.00
1773 Jun 7 2010 12:00AM 125.00
1773 Apr 19 2006 12:00AM 99.00
1817 Jun 2 2008 12:00AM 109.00
1825 Feb 14 2006 12:00AM 99.00
1828 Dec 3 2008 12:00AM 135.00
1828 Jul 15 2009 12:00AM 135.00

--Desired output (Only those rows with the latest date):
1657 Nov 10 2009 12:00AM 150.00
1773 Jun 7 2010 12:00AM 125.00
1817 Jun 2 2008 12:00AM 109.00
1825 Feb 14 2006 12:00AM 99.00
1828 Jul 15 2009 12:00AM 135.00

I tried Select ProfileID, Max(Date), Paid, even added a Distinct to the ProfileID, but keep getting duplicate ProfileID's.

TIA

Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396165 Visits: 43185
JaybeeSQL - Wednesday, July 11, 2018 4:08 PM
Hi all,
I'm trying to get the latest date for every distinct value in a column:
CREATE TABLE [dbo].[Ledger](
[ID] [int] NOT NULL,
[ProfileId] [int] NULL,
[Date] [datetime] NULL,
[Time] [datetime] NULL

) ON [PRIMARY]
GO
--Sample Data
--Select Top 8 ProfileId, Date, Paid
--From Ledger As L
1657 Nov 10 2009 12:00AM 150.00
1657 May 8 2009 12:00AM 150.00
1773 Jun 7 2010 12:00AM 125.00
1773 Apr 19 2006 12:00AM 99.00
1817 Jun 2 2008 12:00AM 109.00
1825 Feb 14 2006 12:00AM 99.00
1828 Dec 3 2008 12:00AM 135.00
1828 Jul 15 2009 12:00AM 135.00

--Desired output (Only those rows with the latest date):
1657 Nov 10 2009 12:00AM 150.00
1773 Jun 7 2010 12:00AM 125.00
1817 Jun 2 2008 12:00AM 109.00
1825 Feb 14 2006 12:00AM 99.00
1828 Jul 15 2009 12:00AM 135.00

I tried Select ProfileID, Max(Date), Paid, even added a Distinct to the ProfileID, but keep getting duplicate ProfileID's.

TIA


Try this:

WITH Base AS (
SELECT
[l].[ProfileId]
, [l].[Date]
, [l].[Paid]
, [rn] = ROW_NUMBER() OVER (PARTITION BY [l].[ProfileId] ORDER BY [l].[Date] DESC)
FROM
[dbo].[Ledger] AS [l]
)
SELECT
[b].[ProfileId]
, [b].[Date]
, [b].[Paid]
FROM
[base] AS [b]
WHERE
[b].[rn] = 1;



Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
JaybeeSQL
JaybeeSQL
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2619 Visits: 986
Thanks bud, that code works stand-alone, now I'm trying to do a couple of joins to filter;


Inner Join personalprofiles PP
ON
L.ProfileId = PP.ID
Inner Join CurrentStudentMembership As CSM
on
CSM.[First name] = PP.[Fname]
And CSM.[Last name] = PP.[Lname]
Where [l].[Paid] > 0

But wherever I put them, I keep getting
Msg 4104, Level 16, State 1, Line 1160
The multi-part identifier "CSM.First name" could not be bound.
Msg 4104, Level 16, State 1, Line 1161
The multi-part identifier "PP.Fname" could not be bound.
Msg 4104, Level 16, State 1, Line 1162
The multi-part identifier "CSM.Last name" could not be bound.
Msg 4104, Level 16, State 1, Line 1163
The multi-part identifier "PP.Lname" could not be bound.
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396165 Visits: 43185
JaybeeSQL - Wednesday, July 11, 2018 5:03 PM
Thanks bud, that code works stand-alone, now I'm trying to do a couple of joins to filter;


Inner Join personalprofiles PP
ON
L.ProfileId = PP.ID
Inner Join CurrentStudentMembership As CSM
on
CSM.[First name] = PP.[Fname]
And CSM.[Last name] = PP.[Lname]
Where [l].[Paid] > 0

But wherever I put them, I keep getting
Msg 4104, Level 16, State 1, Line 1160
The multi-part identifier "CSM.First name" could not be bound.
Msg 4104, Level 16, State 1, Line 1161
The multi-part identifier "PP.Fname" could not be bound.
Msg 4104, Level 16, State 1, Line 1162
The multi-part identifier "CSM.Last name" could not be bound.
Msg 4104, Level 16, State 1, Line 1163
The multi-part identifier "PP.Lname" could not be bound.


Can't help without the entire query and the DDL for the tables.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
JaybeeSQL
JaybeeSQL
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2619 Visits: 986
It's all good I cracked the joins, just had to repeat the joins twice as such...

WITH Base AS (
SELECT
CSM.[First name]
,PP.[Fname]
,CSM.[Last name]
,PP.[Lname]
,[l].[ProfileId]
, [l].[Date]
, [l].[Paid]
, [rn] = ROW_NUMBER() OVER (PARTITION BY [l].[ProfileId] ORDER BY [l].[Date] DESC)
FROM
[dbo].[Ledger] AS [l]
Inner Join personalprofiles PP
ON
L.ProfileId = PP.ID
Inner Join CurrentStudentMembership As CSM
on
CSM.[First name] = PP.[Fname]
And CSM.[Last name] = PP.[Lname]
Where [l].[Paid] > 0
)
SELECT
CSM.[First name]
,PP.[Fname]
,CSM.[Last name]
,PP.[Lname]
, [b].[ProfileId]
, [b].[Date]
, [b].[Paid]
FROM
[base] AS [b]
Inner Join Ledger L
on [b].[ProfileId] = L.[ProfileId]
Inner Join personalprofiles PP
ON
L.ProfileId = PP.ID
Inner Join CurrentStudentMembership As CSM
on
CSM.[First name] = PP.[Fname]
And CSM.[Last name] = PP.[Lname]
Where [l].[Paid] > 0
and [b].[rn] = 1;
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396165 Visits: 43185
JaybeeSQL - Wednesday, July 11, 2018 5:24 PM
It's all good I cracked the joins, just had to repeat the joins twice as such...

WITH Base AS (
SELECT
CSM.[First name]
,PP.[Fname]
,CSM.[Last name]
,PP.[Lname]
,[l].[ProfileId]
, [l].[Date]
, [l].[Paid]
, [rn] = ROW_NUMBER() OVER (PARTITION BY [l].[ProfileId] ORDER BY [l].[Date] DESC)
FROM
[dbo].[Ledger] AS [l]
Inner Join personalprofiles PP
ON
L.ProfileId = PP.ID
Inner Join CurrentStudentMembership As CSM
on
CSM.[First name] = PP.[Fname]
And CSM.[Last name] = PP.[Lname]
Where [l].[Paid] > 0
)
SELECT
CSM.[First name]
,PP.[Fname]
,CSM.[Last name]
,PP.[Lname]
, [b].[ProfileId]
, [b].[Date]
, [b].[Paid]
FROM
[base] AS [b]
Inner Join Ledger L
on [b].[ProfileId] = L.[ProfileId]
Inner Join personalprofiles PP
ON
L.ProfileId = PP.ID
Inner Join CurrentStudentMembership As CSM
on
CSM.[First name] = PP.[Fname]
And CSM.[Last name] = PP.[Lname]
Where [l].[Paid] > 0
and [b].[rn] = 1;


Try this instead:

WITH [Base] AS
(
SELECT
[l].[ProfileId]
, [l].[Date]
, [l].[Paid]
, [rn] = ROW_NUMBER() OVER (PARTITION BY
[l].[ProfileId]
ORDER BY
[l].[Date] DESC
)
FROM
[dbo].[Ledger] AS [l]
WHERE
[l].[Paid] > 0
)
SELECT
[CSM].[First name]
, [PP].[Fname]
, [CSM].[Last name]
, [PP].[Lname]
, [b].[ProfileId]
, [b].[Date]
, [b].[Paid]
FROM
[Base] AS [b]
INNER JOIN [personalprofiles] [PP]
ON [b].[ProfileId] = [PP].[ID]
INNER JOIN [CurrentStudentMembership] AS [CSM]
ON [CSM].[First name] = [PP].[Fname]
AND [CSM].[Last name] = [PP].[Lname]
WHERE
[b].[rn] = 1;
GO


Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
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