Formula to extract unique records only

hrayani

Well-known Member
Joined
Jul 23, 2010
Messages
1,501
Office Version
  1. 2016
Platform
  1. Windows
Hi,

I need a formula to extract only the first occurrence of the data or unique records I can say. The formula should
look all the 3 columns in a row and should treat it as a duplicate if all the 3 cells are equal - otherwise not.

here is a sample data in A2:C17

ArticleQualityUnit
AA1Kgs
BB2Pair
DD3Dozen
EE4Grams
AA1Kgs
BB2Pair
AA1Kgs
AA1Kgs
DD3Dozen
AA3Pair
AA5Dozen
AA5Grams
AA1Kgs
AA1Kgs
AA1Kgs
AA1Kgs

<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>
</tbody>


unique data required in columns H2:J17

in the above case the answer in H2:J17 would be

ArticleQualityUnit
AA1Kgs
BB2Pair
DD3Dozen
EE4Grams
AA3Pair
AA5Dozen
AA5Grams

<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>
</tbody>


Rest all rows till 17 will show blanks as there is no more unique data.

If any one can provide a solution

Regards,

Humayun
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Copy A1:C17 to H1:J17, go on data tab and click remove duplicates (then tick "my data has a header")
 
Last edited:
Upvote 0
Thanks for reply,

Yes i can do that manually but i need a formula to do that coz the actual data will keep on adding. So if there is a formula then i do not have to remove duplicates manually everytime....

I found one formula which works for a single column....

=IFERROR(INDEX($A$2:$A$17, MATCH(0,COUNTIF($H$1:H1, $A$2:$A$17), 0)),"")

but i dont know how to get it to work for 3 columns...

Any Idea ???
 
Last edited:
Upvote 0
Hello,

In cell H2 ... test following Array Formula:

Code:
=IFERROR(INDEX(A$2:A$17,MATCH(0,COUNTIF($F$1:F1,$A$2:$A$17&$B$2:$B$17&$C$2:$C$17),0)),"")

Hope this will help
 
Upvote 0
It is possible with an array formula {}, but could not find it yet.
A better solution than formulae going down and showing "" if error is to set this data in a table (so range extend automatically, no need to update the source), make a pivot
(tabular form)
of the table in h1 putting Article, quantity and unit in rows and refresh the pivot automatically when you activate the sheet:
right click sheet name, click view code and paste
Code:
Private Sub Worksheet_Activate()
ActiveWorkbook.RefreshAll
End Sub
 
Last edited:
Upvote 0
Hi James,

I tried it... All it is giving the first cell value in all the cell till row 17 :(
 
Upvote 0
A better solution than formulae going down and showing "" if error is to set this data in a table (so range extend automatically, no need to update the source), make a pivot


The formula wont do down more than 70 rows... coz there will not be more than 70 unique values... Yes the actual data currently runs at over 600 rows and will be increasing everyday.

I am not familiar with tables and pivot..


It is possible with an array formula {}, but could not find it yet

Yes u r right... I am hopefull i will get one here :)
 
Upvote 0
Hello,

You can test following:

Code:
Sub Unique3Cols()
    With Worksheets("Sheet1")
        .Range("A1:C17").AdvancedFilter Action:=xlFilterCopy, CopyToRange:=.Range("H1:J1"), Unique:=True
    End With
End Sub

HTH
 
Upvote 0
Maybe something like this?


Book1
ABC
1ArticleQualityUnit
2AA1Kgs
3BB2Pair
4DD3Dozen
5EE4Grams
6AA1Kgs
7BB2Pair
8AA1Kgs
9AA1Kgs
10DD3Dozen
11AA3Pair
12AA5Dozen
13AA5Grams
14AA1Kgs
15AA1Kgs
16AA1Kgs
17AA1Kgs
18
19
20
21Count7
22ArticleQualityUnit
23AA1Kgs
24BB2Pair
25DD3Dozen
26EE4Grams
27AA3Pair
28AA5Dozen
29AA5Grams
30
31
Sheet2
Cell Formulas
RangeFormula
C21{=SUM(IF(FREQUENCY(MATCH($A$2:$A$17&$B$2:$B$17&$C$2:$C$17,$A$2:$A$17&$B$2:$B$17&$C$2:$C$17,0),ROW($A$2:$A$18)-ROW($A$1)),1,0))}
A23{=IF(ROWS(A$23:A23)>$C$21,"",INDEX(A$2:A$17,SMALL(IF(COUNTIFS($A$22:$A22,$A$2:$A$17,$B$22:$B22,$B$2:$B$17,$C$22:$C22,$C$2:$C$17)=0,ROW($A$2:$A$17)-ROW($A$1)),1)))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Hi Nishant,

Thanks for the solution.... working perfect....

Is it possible to merge these 2 formulas.... I dont know if i am sounding weird..
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,982
Messages
6,122,573
Members
449,089
Latest member
Motoracer88

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