Dependable Dynamic Unique List

qwertytrewq

New Member
Joined
Apr 19, 2018
Messages
9
Hello, I have data from which i need to extract unique list. i have everything up and running but my data has lot more rows n columns and excel takes forever to calculate it. Please suggest way to simplify these formulas to cut back on processing time or any if there is other way to get the desired dynamic list then please suggest that too.

[TABLE="class: grid, width: 1464"]
<tbody>[TR]
[TD][/TD]
[TD]Column A[/TD]
[TD]Column B[/TD]
[TD]Column C[/TD]
[TD]Column D[/TD]
[TD]Column E[/TD]
[TD]Column F[/TD]
[TD]Column G[/TD]
[TD]Column H[/TD]
[TD]Column I[/TD]
[TD]Column J[/TD]
[TD]Column K[/TD]
[TD]Column L[/TD]
[TD]Column M[/TD]
[TD]Column N[/TD]
[TD]Column O[/TD]
[/TR]
[TR]
[TD]Row 1[/TD]
[TD="colspan: 5, align: center"]Below is Sample Data[/TD]
[TD][/TD]
[TD="colspan: 3"]Below is Calculation step to get Unique Value in Sequence as in Sample Data[/TD]
[TD][/TD]
[TD="colspan: 5"]Below is Desired Dynamic List obtained from Sample Data[/TD]
[/TR]
[TR]
[TD]Row 2[/TD]
[TD="colspan: 2, align: center"]Sample[/TD]
[TD="colspan: 3, align: center"]Data related to the sample[/TD]
[TD][/TD]
[TD][/TD]
[TD="colspan: 2, align: center"][/TD]
[TD="colspan: 3, align: center"][/TD]
[/TR]
[TR]
[TD]Row 3[/TD]
[TD]First Name[/TD]
[TD]Last Name[/TD]
[TD]data1[/TD]
[TD]data2[/TD]
[TD]data3[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]First Name[/TD]
[TD]Last Name[/TD]
[TD]data1[/TD]
[TD]data2[/TD]
[TD]data3[/TD]
[/TR]
[TR]
[TD]Row 4[/TD]
[TD]John[/TD]
[TD]Doe[/TD]
[TD]x[/TD]
[TD]y[/TD]
[TD]z[/TD]
[TD][/TD]
[TD]John ; Doe[/TD]
[TD]Jane ; Dou[/TD]
[TD]John ; Dow[/TD]
[TD][/TD]
[TD]John[/TD]
[TD]Dow[/TD]
[TD]z[/TD]
[TD]x[/TD]
[TD]y[/TD]
[/TR]
[TR]
[TD]Row 5[/TD]
[TD]John[/TD]
[TD]Dow[/TD]
[TD]z[/TD]
[TD]x[/TD]
[TD]y[/TD]
[TD][/TD]
[TD]John ; Dow[/TD]
[TD]Jane ; Dow[/TD]
[TD]John ; Dou[/TD]
[TD][/TD]
[TD]John[/TD]
[TD]Dou[/TD]
[TD]x[/TD]
[TD]z[/TD]
[TD]y[/TD]
[/TR]
[TR]
[TD]Row 6[/TD]
[TD]John[/TD]
[TD]Dou[/TD]
[TD]x[/TD]
[TD]z[/TD]
[TD]y[/TD]
[TD][/TD]
[TD]John ; Dou[/TD]
[TD]Jane ; Doe[/TD]
[TD]John ; Doe[/TD]
[TD][/TD]
[TD]John[/TD]
[TD]Doe[/TD]
[TD]x[/TD]
[TD]y[/TD]
[TD]z[/TD]
[/TR]
[TR]
[TD]Row 7[/TD]
[TD]John[/TD]
[TD]Doe[/TD]
[TD]y[/TD]
[TD]z[/TD]
[TD]x[/TD]
[TD][/TD]
[TD]John ; Doe[/TD]
[TD]John ; Doe[/TD]
[TD]Jane ; Doe[/TD]
[TD][/TD]
[TD]Jane[/TD]
[TD]Doe[/TD]
[TD]y[/TD]
[TD]x[/TD]
[TD]z[/TD]
[/TR]
[TR]
[TD]Row 8[/TD]
[TD]Jane[/TD]
[TD]Doe[/TD]
[TD]y[/TD]
[TD]x[/TD]
[TD]z[/TD]
[TD][/TD]
[TD]Jane ; Doe[/TD]
[TD]John ; Dou[/TD]
[TD]Jane ; Dow[/TD]
[TD][/TD]
[TD]Jane[/TD]
[TD]Dow[/TD]
[TD]z[/TD]
[TD]y[/TD]
[TD]x[/TD]
[/TR]
[TR]
[TD]Row 9[/TD]
[TD]Jane[/TD]
[TD]Dow[/TD]
[TD]z[/TD]
[TD]y[/TD]
[TD]x[/TD]
[TD][/TD]
[TD]Jane ; Dow[/TD]
[TD]John ; Dow[/TD]
[TD]Jane ; Dou[/TD]
[TD][/TD]
[TD]Jane[/TD]
[TD]Dou[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]x[/TD]
[/TR]
[TR]
[TD]Row 10[/TD]
[TD]Jane[/TD]
[TD]Dou[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD][/TD]
[TD]Jane ; Dou[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="align: center"]#VALUE![/TD]
[TD="align: center"]#VALUE![/TD]
[TD="align: center"]#N/A[/TD]
[TD="align: center"]#N/A[/TD]
[TD="align: center"]#N/A[/TD]
[/TR]
[TR]
[TD]Row 11[/TD]
[TD]Jane[/TD]
[TD]Dou[/TD]
[TD]y[/TD]
[TD]y[/TD]
[TD]y[/TD]
[TD][/TD]
[TD]Jane ; Dou[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="align: center"]#VALUE![/TD]
[TD="align: center"]#VALUE![/TD]
[TD="align: center"]#N/A[/TD]
[TD="align: center"]#N/A[/TD]
[TD="align: center"]#N/A[/TD]
[/TR]
</tbody>[/TABLE]

A4:E11 is raw data which will get updated from time to time.
K4:O11 is the desired data obtained.

A4:B4 is the data from which unique values to be extracted ( there are two repeats A7:B7 & A11:B11 , C4:E11 plays no role whatsover in deciding uniqueness)

G4:G11 combines A4:E11 to decide the Unique value ( I could find no other way to calculate this than to actually combine the two columns, ";" is there to later search and seperate the columns.

H4:H11 is where duplicate values are removed.

I4:I11 repeated the formula in H4:H11 to get the value in sequence.

K4:L11 is where the Value obtained from I4:I11 is seperated out in two columns as in Sample data.

M4:O11 respective Data from C4:E11 is Indexed Matched.


Formula in G4 : =A4&" ; "&B4
Formula in H4 : =IFERROR(LOOKUP(2,1/(COUNTIF($H$3:H3,$G$4:$G$11)=0),$G$4:$G$11),"")
Formula in I4 : =IFERROR(LOOKUP(2,1/(COUNTIF($I$3:I3,$H$4:$H$11)=0),$H$4:$H$11),"")
Formula in K4 : =LEFT(I4,SEARCH(" ; ",I4)-1)
Formula in L4 : =RIGHT(I4,LEN(I4)-SEARCH(" ; ",I4)-2)
Formula in M4 : =INDEX($C$4:$C$11,MATCH(1,INDEX((K4=$A$4:$A$11)*(L4=$B$4:$B$11),0,1),0))
Formula in N4 : =INDEX($D$4:$D$11,MATCH(1,INDEX((K4=$A$4:$A$11)*(L4=$B$4:$B$11),0,1),0))
Formula in O4 : =INDEX($E$4:$E$11,MATCH(1,INDEX((K4=$A$4:$A$11)*(L4=$B$4:$B$11),0,1),0))

Thanks for taking a look at this.

P.S. : Ignore the errors will use IFERROR later.
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Re: Dependable Dynamic Unique List - Little help here

Care to post the desired end result?

care to read the whole post?
i dont think my post could be any more informative than it already is....2nd line below table "K4:O11 is the desired data obtained" or in other words K4:O11 is the desired end result.
 
Upvote 0
Re: Dependable Dynamic Unique List - Little help here

care to read the whole post?
i dont think my post could be any more informative than it already is....2nd line below table "K4:O11 is the desired data obtained" or in other words K4:O11 is the desired end result.


Book1
ABCDEGHIJKL
1First NameLast Namedata1data2data36
2JohnDoexyzIdxFirst NameLast Namedata1data2data3
3JohnDowzxy1JohnDoexyz
4JohnDouxzy2JohnDowzxy
5JohnDoeyzx3JohnDouxzy
6JaneDoeyxz5JaneDoeyxz
7JaneDowzyx6JaneDowzyx
8JaneDouxxx7JaneDouxxx
9JaneDouyyy
Sheet1 (2)


In G1 control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(MATCH($A$2:$A$9&"|"&$B$2:$B$9,$A$2:$A$9&"|"&$B$2:$B$9,0),ROW($A$2:$E$9)-ROW(INDEX($A$2:$E$9,1,1))+1),1))

In G3 control+shift+enter, not just enter, and copy down:

=IF(ROWS($G$3:G3)>$G$1,"",SMALL(IF(FREQUENCY(MATCH($A$2:$A$9&"|"&$B$2:$B$9,$A$2:$A$9&"|"&$B$2:$B$9,0),ROW($A$2:$E$9)-ROW(INDEX($A$2:$E$9,1,1))+1),ROW($A$2:$E$9)-ROW(INDEX($A$2:$E$9,1,1))+1),ROWS($G$3:G3)))

In H3 just enter, copy across to L3, and down:

=IF($G3="","",INDEX($A$2:$E$9,$G3,MATCH(H$2,$A$1:$E$1,0)))
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,252
Members
452,623
Latest member
Techenthusiast

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