 |
SQL Server 2000 General discussion of Microsoft SQL Server -- for topics that don't fit in one of the more specific SQL Server forums. version 2000 only. There's a new forum for SQL Server 2005. |
Welcome to the p2p.wrox.com Forums.
You are currently viewing the SQL Server 2000 section of the Wrox Programmer to Programmer discussions. This is a community of software programmers and website developers including Wrox book authors and readers. New member registration was closed in 2019. New posts were shut off and the site was archived into this static format as of October 1, 2020. If you require technical support for a Wrox book please contact http://hub.wiley.com
|
|
|

December 19th, 2007, 04:08 PM
|
Friend of Wrox
|
|
Join Date: Jul 2003
Posts: 599
Thanks: 6
Thanked 3 Times in 3 Posts
|
|
One Record From Each Group - Query
Hi,
Thank you for your response. Very much appreciated.
I have this query:
Select Inventory.InvFloat5 As InvFloat5, Inventory.CompTypeID, ComponentHistory.InvID, CompHistDate From ComponentHistory Inner Join Inventory On ComponentHistory.InvID = Inventory.InvID Inner Join Subareas On Subareas.SubID = Inventory.SubID Inner Join ComponentTypes On Inventory.CompTypeID = ComponentTypes.CompTypeID Where Subareas.SubID = 9193 And Inventory.RuleID = 32 And CompHistStatus = 1 And CONVERT(Varchar(10),DATEPART(q,CompHistDate)) + '/' + CONVERT(Varchar(10),DATEPART(yy, CompHistDate)) <= '4/2007' Order By Inventory.CompTypeID Asc, CompHistDate Desc ;
This is the data that's being pulled:
InvFloat5 CompTypeID InvID CompHistDate
13.0 7 315395 2006-10-01 00:00:00.000
2.0 9 315402 2006-10-01 00:00:00.000
3.0 10 1293606 2007-12-18 00:00:00.000
3.0 10 315396 2007-08-10 00:00:00.000
3.0 10 1293792 2006-12-01 00:00:00.000
3.0 10 1293790 2006-01-01 00:00:00.000
3.0 10 1293600 2005-12-11 00:00:00.000
6.0 11 1293789 2007-12-18 00:00:00.000
What I'm trying to do and haven't figured out yet is how to only get the one value per CompTypeID. Like for ComptypeID 10 I only want the record with InvID of 1293606 since it is the latest value that is not greater than the quarter being searched.
I tried Top 1 and that only gave me one record and I thought that maybe if I grouped them it would pull a Distinct CompTypeID but that didn't work either.
Appreciate any input on this.
Thanks,
Richard
|

December 20th, 2007, 03:59 PM
|
Friend of Wrox
|
|
Join Date: Jul 2003
Posts: 599
Thanks: 6
Thanked 3 Times in 3 Posts
|
|
I think I have this figured out. Here is the problem more simply stated. Here's what the data looks like.
Float5 CompType Date
13 1 12/1/2005
20 1 10/1/2006
1 2 10/1/2006
34 3 8/1/2005
5 3 8/1/2007
67 3 12/1/2007
So the problem is that I need to pull only the latest record for each CompType. And here's what I came up with.
SELECT Float5, CompType FROM InventoryCount As A
WHERE TheDate = (SELECT MAX(TheDate) FROM InventoryCount As B WHERE B.CompType = A.CompType)
And it gives me exactly what I was looking for:
Float5 CompType
67 3
1 2
20 1
I get only the float value for the latest date entry.
|

December 28th, 2007, 01:25 AM
|
Friend of Wrox
|
|
Join Date: Oct 2007
Posts: 130
Thanks: 0
Thanked 3 Times in 3 Posts
|
|
I am not sure your solution will work for every situation. For example if records are not there in transaction table for particular computetype then that compute type will not come in result.
You can use LEFT OUTER or INNER JOIN for further joins to get required output.
I would prefer following code.
SELECT A.Float5, A.CompType
FROM InventoryCount As A
LEFT OUTER JOIN (SELECT MAX(TheDate) Thedate,CompType FROM InventoryCount As B group by CompType) B
WHERE B.CompType = A.CompType AND A.TheDate=B.TheDate
urt
|

December 29th, 2007, 05:34 PM
|
Friend of Wrox
|
|
Join Date: Jul 2003
Posts: 599
Thanks: 6
Thanked 3 Times in 3 Posts
|
|
Thanks for the reply. Your query throws an error in QA.
Incorrect syntax near the keyword 'WHERE'.
I tried working with the query but couldn't resolve the error. I tried changing the 'WHERE' to 'ON'. The query ran but the results were not what I was looking for.
I like the idea and see where you're going. I did run in to problems with my last query when I had to GROUP BY another parameter.
Thanks for your help.
Richard
CREATE TABLE [InventoryCount] (
[FloatInt] [int] IDENTITY (1, 1) NOT FOR REPLICATION NOT NULL ,
[Float5] [int] NOT NULL ,
[CompType] [int] NOT NULL ,
[TheDate] [datetime] NOT NULL
) ON [PRIMARY]
GO
INSERT INTO [InventoryCount]([Float5], [CompType], [TheDate]) VALUES(13, 1, '12/1/2005')
INSERT INTO [InventoryCount]([Float5], [CompType], [TheDate]) VALUES(20, 1, '10/1/2006')
INSERT INTO [InventoryCount]([Float5], [CompType], [TheDate]) VALUES(1, 2, '10/1/2006')
INSERT INTO [InventoryCount]([Float5], [CompType], [TheDate]) VALUES(34, 3, '8/1/2005')
INSERT INTO [InventoryCount]([Float5], [CompType], [TheDate]) VALUES(5, 3, '8/1/2007')
INSERT INTO [InventoryCount]([Float5], [CompType], [TheDate]) VALUES(67, 3, '12/1/2007')
|

December 31st, 2007, 02:25 AM
|
Friend of Wrox
|
|
Join Date: Oct 2007
Posts: 130
Thanks: 0
Thanked 3 Times in 3 Posts
|
|
Just change LEFT OUTER JOIN to INNER JOIN
urt
|

December 31st, 2007, 02:29 AM
|
Friend of Wrox
|
|
Join Date: Oct 2007
Posts: 130
Thanks: 0
Thanked 3 Times in 3 Posts
|
|
In my first reply I quoted following
"You can use LEFT OUTER or INNER JOIN for further joins to get required output."
Final Query
SELECT A.Float5, A.CompType,b.Thedate FROM InventoryCount as A
INNER JOIN (SELECT MAX(TheDate) Thedate,CompType FROM InventoryCount group by CompType) as B
on B.CompType = A.CompType AND A.TheDate=B.TheDate
urt
|

January 2nd, 2008, 01:52 PM
|
Friend of Wrox
|
|
Join Date: Jul 2003
Posts: 599
Thanks: 6
Thanked 3 Times in 3 Posts
|
|
Thank you!
I need to keep testing this to see if it will work in all situations and modify accordingly. It is working for this query though.
I really appreciate you taking the time to work on this.
Richard
|

January 3rd, 2008, 12:08 AM
|
Friend of Wrox
|
|
Join Date: Oct 2007
Posts: 130
Thanks: 0
Thanked 3 Times in 3 Posts
|
|
Welcome
urt
|
|
 |