Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


MAX Function Problem


MAX Function Problem

Author
Message
CoryJ72
CoryJ72
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 44
I need to query a table that has three columns 1st RecordID (Primary Key, Unique), 2nd ItemID (non-unique) and 3rd Cost(currency). I need to return RecordID, ItemID( Group by) and Cost (Max) only one record per ItemID.

Hope some one can help.
Jason-299789
Jason-299789
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: 1132 Visits: 3229
Can you supply the DDL and DML as well as sample data and expected results as this will help us understand the data and what results you want.

Is there a reason why you need to include RecordId in the output?

_________________________________________________________________________
SSC Guide to Posting and Best Practices
CoryJ72
CoryJ72
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 44
What is DDL and DML?
CoryJ72
CoryJ72
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 44
Current Data:

RecordID   ItemID   MaxOfCost
43392   3880    $50.00
39056   3881    $93.75
33941   3881    $97.50
33970   3881    $97.50
38950   3881    $98.75
40417   3881    $96.56
36491   3882    $30.00
37265   3883    $6.50
35054   3883    $4.50
33658   3884    $14.94
36585   3884    $18.77
33134   3884    $14.75


Results should be:
RecordID   ItemID   MaxOfCost
43392   3880    $50.00
38950   3881    $98.75
36491   3882    $30.00
37265   3883    $6.50
36585   3884    $18.77

I require the RecordID to use in another query.
Jason-299789
Jason-299789
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: 1132 Visits: 3229
Hi Cory,

DDL is Data Definition language, eg Table defs etc
DML is Data Manipulation language, eg the Select/Insert statements

I see you posted some sample data so I'll have a look at it.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
In the future, you should provide DDL and consumable sample data in the format I've included below.


-- DDL
DECLARE @T TABLE
(RecordID INT, ItemID INT, MaxOfCost MONEY)

-- Consumable sample data
INSERT INTO @T
SELECT 43392,3880,$50.00
UNION ALL SELECT 39056,3881,$93.75
UNION ALL SELECT 33941,3881,$97.50
UNION ALL SELECT 33970,3881,$97.50
UNION ALL SELECT 38950,3881,$98.75
UNION ALL SELECT 40417,3881,$96.56
UNION ALL SELECT 36491,3882,$30.00
UNION ALL SELECT 37265,3883,$6.50
UNION ALL SELECT 35054,3883,$4.50
UNION ALL SELECT 33658,3884,$14.94
UNION ALL SELECT 36585,3884,$18.77
UNION ALL SELECT 33134,3884,$14.75

;WITH MyData AS (
SELECT RecordID, ItemID, MaxOfCost
,n=ROW_NUMBER() OVER (PARTITION BY ItemID ORDER BY MaxOfCost DESC)
FROM @T)
SELECT RecordID, ItemID, MaxOfCost
FROM MyData
WHERE n = 1




Hopefully this provides the results you seek but let us know.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Jason-299789
Jason-299789
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: 1132 Visits: 3229
heres a quick and dirty way


CREATE Table #results
(
RecordId Int
,ItemId Int
,cost Decimal(38,2)
)

Insert into #results
values (43392, 3880 ,50.00)
,(39056, 3881, 93.75)
,(33941, 3881, 97.50)
,(33970, 3881, 97.50)
,(38950, 3881, 98.75)
,(99999, 3881, 98.75)
,(40417, 3881, 96.56)
,(36491, 3882, 30.00)
,(37265, 3883, 6.50)
,(35054, 3883 ,4.50)
,(33658, 3884, 14.94)
,(36585, 3884,18.77)
,(33134, 3884, 14.75)

Select r.RecordId,r.ItemId,r.cost
From #results r
JOIN (Select ItemId,MAX(cost) mcost
      from #results
      group by ItemId) m
   on m.ItemId=r.ItemId
      and mcost=r.cost



This assumes that the Max(Cost) per Item Id is unique.

Eg if you added a row 9999,3881,98.75 and ran this you would get two rows in the output

36585   3884   18.77
37265   3883   6.50
36491   3882   30.00
38950   3881   98.75
99999   3881   98.75
43392   3880   50.00

I dont know if thats what you want.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
Jason-299789
Jason-299789
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: 1132 Visits: 3229
dwain.c (10/30/2012)
In the future, you should provide DDL and consumable sample data in the format I've included below.


-- DDL
DECLARE @T TABLE
(RecordID INT, ItemID INT, MaxOfCost MONEY)

-- Consumable sample data
INSERT INTO @T
SELECT 43392,3880,$50.00
UNION ALL SELECT 39056,3881,$93.75
UNION ALL SELECT 33941,3881,$97.50
UNION ALL SELECT 33970,3881,$97.50
UNION ALL SELECT 38950,3881,$98.75
UNION ALL SELECT 40417,3881,$96.56
UNION ALL SELECT 36491,3882,$30.00
UNION ALL SELECT 37265,3883,$6.50
UNION ALL SELECT 35054,3883,$4.50
UNION ALL SELECT 33658,3884,$14.94
UNION ALL SELECT 36585,3884,$18.77
UNION ALL SELECT 33134,3884,$14.75

;WITH MyData AS (
SELECT RecordID, ItemID, MaxOfCost
,n=ROW_NUMBER() OVER (PARTITION BY ItemID ORDER BY MaxOfCost DESC)
FROM @T)
SELECT RecordID, ItemID, MaxOfCost
FROM MyData
WHERE n = 1




Hopefully this provides the results you seek but let us know.


Thats was quick dwain, and a nice solution though it will suppress any rows that have the same MAX(cost) as another row.

I suppose the question outstanding is what if there are two rows with the same ItemId and Cost, do you want all rows returned or just one, if just one which one takes takes precedence?

_________________________________________________________________________
SSC Guide to Posting and Best Practices
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
Jason-299789 (10/30/2012)
dwain.c (10/30/2012)
In the future, you should provide DDL and consumable sample data in the format I've included below.


-- DDL
DECLARE @T TABLE
(RecordID INT, ItemID INT, MaxOfCost MONEY)

-- Consumable sample data
INSERT INTO @T
SELECT 43392,3880,$50.00
UNION ALL SELECT 39056,3881,$93.75
UNION ALL SELECT 33941,3881,$97.50
UNION ALL SELECT 33970,3881,$97.50
UNION ALL SELECT 38950,3881,$98.75
UNION ALL SELECT 40417,3881,$96.56
UNION ALL SELECT 36491,3882,$30.00
UNION ALL SELECT 37265,3883,$6.50
UNION ALL SELECT 35054,3883,$4.50
UNION ALL SELECT 33658,3884,$14.94
UNION ALL SELECT 36585,3884,$18.77
UNION ALL SELECT 33134,3884,$14.75

;WITH MyData AS (
SELECT RecordID, ItemID, MaxOfCost
,n=ROW_NUMBER() OVER (PARTITION BY ItemID ORDER BY MaxOfCost DESC)
FROM @T)
SELECT RecordID, ItemID, MaxOfCost
FROM MyData
WHERE n = 1




Hopefully this provides the results you seek but let us know.


Thats was quick dwain, and a nice solution though it will suppress any rows that have the same MAX(cost) as another row.

I suppose the question outstanding is what if there are two rows with the same ItemId and Cost, do you want all rows returned or just one, if just one which one takes takes precedence?


True enough. Although you could use RANK() instead of ROW_NUMBER() to resolve that quandary.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
CoryJ72
CoryJ72
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 44
Jason-299789 (10/30/2012)
heres a quick and dirty way


CREATE Table #results
(
RecordId Int
,ItemId Int
,cost Decimal(38,2)
)

Insert into #results
values (43392, 3880 ,50.00)
,(39056, 3881, 93.75)
,(33941, 3881, 97.50)
,(33970, 3881, 97.50)
,(38950, 3881, 98.75)
,(99999, 3881, 98.75)
,(40417, 3881, 96.56)
,(36491, 3882, 30.00)
,(37265, 3883, 6.50)
,(35054, 3883 ,4.50)
,(33658, 3884, 14.94)
,(36585, 3884,18.77)
,(33134, 3884, 14.75)

Select r.RecordId,r.ItemId,r.cost
From #results r
JOIN (Select ItemId,MAX(cost) mcost
      from #results
      group by ItemId) m
   on m.ItemId=r.ItemId
      and mcost=r.cost



This assumes that the Max(Cost) per Item Id is unique.

Eg if you added a row 9999,3881,98.75 and ran this you would get two rows in the output

36585   3884   18.77
37265   3883   6.50
36491   3882   30.00
38950   3881   98.75
99999   3881   98.75
43392   3880   50.00

I dont know if thats what you want.


Sorry no i need to return only one result per ItemID. No preference on which one just need one result. I now see why you are after the DDL and DML.
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