A Query that only shows the lastest/Last record for each vendor

gheyman

Well-known Member
Joined
Nov 14, 2005
Messages
2,332
Office Version
  1. 365
Platform
  1. Windows
If I had a table with vendor history of each purchase they made (the table has the same customer listed numerous times under VendorName). The table has a "CreatedDate" field that puts the date the record was created in it and the table also has an AutoCount field "ID_NISTSL". So there are two ways to determine which is the last record entered into the table.

Is there a way to query (or only see) the last record (most recent) for each customer?

Thanks!
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Re: Access: A Query that only shows the lastest/Last record for each vendor

I would recommend using the date field. If the AutoCount field is an Autonum field, you cannot rely on it always to be increasing (though it usually is, it cannot guarantee it).

Here is SQL code for a query that should do what you want:
Code:
SELECT Table1.*
FROM Table1
INNER JOIN
[COLOR=#0000ff](SELECT Table1.VendorName, Max(Table1.CreatedDate) AS MaxOfCreatedDate[/COLOR]
[COLOR=#0000ff]FROM Table1[/COLOR]
[COLOR=#0000ff]GROUP BY Table1.VendorName) as Lst[/COLOR]
ON Table1.VendorName = Lst.VendorName AND Table1.CreatedDate = Lst.MaxOfCreatedDate;
Just change all references of "Table1" with the name of your table.
 
Upvote 0
Re: Access: A Query that only shows the lastest/Last record for each vendor

Thanks, Joe

Wht if I wanted to group by two fields VendorName and CommType? Is it possible to group by more than one?

And can you add Criteria?

WHERE (((tbl_NIS_TSL.VendorName) Like [Forms]![frm_NIS_TSL]![Combo227]) AND ((tbl_NIS_TSL.CommType) Like [Forms]![frm_NIS_TSL]![Combo232]) AND ((tbl_NIS_TSL.Debarred) Like [Forms]![frm_NIS_TSL]![Combo229]) AND ((tbl_NIS_TSL.Approval_Status) Like [Forms]![frm_NIS_TSL]![Combo234]))
ORDER BY tbl_NIS_TSL.VendorName, tbl_NIS_TSL.CreatedDate DESC;
 
Last edited:
Upvote 0
Re: Access: A Query that only shows the lastest/Last record for each vendor

Sure. You would just first add it to both the SELECT and GROUP BY clauses of the query in blue, and then add another AND to the end of the JOIN to join on this field too.

Note that instead of using an embedded query like this, you can do this in two queries, which allows you to do it all using the Query Builder.

Query 1:
This is your Aggregate Query, where you only select the fields you want to group by and the field you want to aggregate by.
You select those fields, and hit the Totals button (looks like a Sigma).
This adds a Totals row with the phrase "Group By" under all three fields.
Change "Group By" to "Max" under the CreatedDate field to return the latest date for each grouping.
So, when this is finished, you have a listing of every unique Grouping, and the latest date for each grouping.

Query 2:
If you want other fields displayed from your table other than the three fields in the previous query, simply join the original table to Query 1, joining on ALL three fields from Query 1.
Then you can elect to return any fields you want from the original table.

That is what the embedded query I originally created does. It can be done either way.
Once built, you do not have to open Query 1 at all, just Query 2.
 
Upvote 0
Re: Access: A Query that only shows the lastest/Last record for each vendor

Thank you!
 
Upvote 0
Re: Access: A Query that only shows the lastest/Last record for each vendor

You are welcome.
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,207
Members
448,554
Latest member
Gleisner2

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top