MAX Formula in VBA

audrey

Active Member
Joined
Jul 30, 2008
Messages
491
Hello,

I have two columns in my excel sheet....

Column A

XYZ
ABC
DEF
XYZ
etc...

Column B
201010
201109
201007
etc...

I want to make a macro that will count only once Columns A values and match the MAX value in Column B.....


is that possible ??
 
Last edited:

Some videos you may like

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Try:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG24Nov57
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Dn [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
    .CompareMode = vbTextCompare
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        [COLOR="Navy"]If[/COLOR] Not .Exists(Dn.Value) [COLOR="Navy"]Then[/COLOR] .Add Dn.Value, Dn(, 2) Else .Item(Dn.Value) = Application.max(.Item(Dn.Value), Dn(, 2))
    [COLOR="Navy"]Next[/COLOR]
Range("C1").Resize(.Count, 2) = Application.Transpose(Array(.Keys, .Items))
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 

audrey

Active Member
Joined
Jul 30, 2008
Messages
491
A step further Mick...

Lets say I have an extra column with country codes

Column A
UK
FRA
DE
US
UK
UK
FRA

Column B
XYZ
ABC
DEF
XYZ
DEF
BBB
AAA

Column C
201010
201109
201007
201104
201103
200105

Can I do the remove duplicates not necessarily based on Column B but also together with Column A and then and match the MAX value in Column C..... ??
 

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Try this for results in "D,E & F".
Code:
[COLOR="Navy"]Sub[/COLOR] MG25Nov36
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Dn [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Q
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
    .CompareMode = vbTextCompare
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        [COLOR="Navy"]If[/COLOR] Not .Exists(Dn.Value & Dn.Offset(, 1).Value) [COLOR="Navy"]Then[/COLOR]
            .Add Dn.Value & Dn.Offset(, 1).Value, Array(Dn, Dn(, 2), Dn(, 3))
        [COLOR="Navy"]Else[/COLOR]
         Q = .Item(Dn.Value & Dn.Offset(, 1).Value)
            Q(2) = Application.max(Q(2), Dn(, 3))
        .Item(Dn.Value & Dn.Offset(, 1).Value) = Q
       [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR]
Range("D1").Resize(.Count, 3) = Application.Transpose(Application.Transpose(.Items))
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 

Watch MrExcel Video

Forum statistics

Threads
1,122,539
Messages
5,596,754
Members
414,097
Latest member
FaeFen

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
Top