Find unique and add a line after the nth unique found

kevinm2

New Member
Joined
Mar 5, 2013
Messages
27
I have looking for a vba to achieve the following, without success:


  1. Count for the number of unique in style Column. Place that count in sku_to_style_count column
  2. When there are more than one sku related to a style column, add a blank row after nth unique style
  3. Copy that style to the style Column and the sku column and also the Style Count to sku_to_style_count column.

Before (Note: there are two styles with more than one sku (ACRE012 and BHF65)
[TABLE="class: grid, width: 380"]
<tbody>[TR]
[TD][/TD]
[TD="align: center"]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]style[/TD]
[TD="align: center"]sku[/TD]
[TD="align: center"]sku_to_style_count[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD]ACRE01[/TD]
[TD]ACR10234[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD]ACRE03[/TD]
[TD]ACR10435[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD]ACRE04[/TD]
[TD]ACR10566[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD]ACRE06[/TD]
[TD]ACR14537[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]6[/TD]
[TD]ACRE012[/TD]
[TD]ACR10538[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]7[/TD]
[TD]ACRE012[/TD]
[TD]ACR10539[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]8[/TD]
[TD]BHF34[/TD]
[TD]BHF54365[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]9[/TD]
[TD]BHF12[/TD]
[TD]BHF04337[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]10[/TD]
[TD]BHF65[/TD]
[TD]BHF73953[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]11[/TD]
[TD]BHF65[/TD]
[TD]BHF73954[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]12[/TD]
[TD]BHF65[/TD]
[TD]BHF73955[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


After (Added added lines are in Bold)
[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD="width: 36"][/TD]
[TD="width: 92, align: center"]A[/TD]
[TD="width: 123, align: center"]B[/TD]
[TD="width: 129, align: center"]C[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]style[/TD]
[TD="align: center"]sku[/TD]
[TD="align: center"]sku_to_style_count[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD]ACRE01[/TD]
[TD]ACR10234[/TD]
[TD="align: center"]1[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD]ACRE03[/TD]
[TD]ACR10435[/TD]
[TD="align: center"]1[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD]ACRE04[/TD]
[TD]ACR10566[/TD]
[TD="align: center"]1[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD]ACRE06[/TD]
[TD]ACR14537[/TD]
[TD="align: center"]1[/TD]
[/TR]
[TR]
[TD="align: center"]6[/TD]
[TD]ACRE012[/TD]
[TD]ACR10538[/TD]
[TD="align: center"]2[/TD]
[/TR]
[TR]
[TD="align: center"]7[/TD]
[TD]ACRE012[/TD]
[TD]ACR10539[/TD]
[TD="align: center"]2[/TD]
[/TR]
[TR]
[TD="align: center"]8
[/TD]
[TD]ACRE012[/TD]
[TD]ACRE012[/TD]
[TD="align: center"]2[/TD]
[/TR]
[TR]
[TD="align: center"]9[/TD]
[TD]BHF34[/TD]
[TD]BHF54365[/TD]
[TD="align: center"]1[/TD]
[/TR]
[TR]
[TD="align: center"]10[/TD]
[TD]BHF12[/TD]
[TD]BHF04337[/TD]
[TD="align: center"]1[/TD]
[/TR]
[TR]
[TD="align: center"]11[/TD]
[TD]BHF65[/TD]
[TD]BHF73953[/TD]
[TD="align: center"]3[/TD]
[/TR]
[TR]
[TD="align: center"]12[/TD]
[TD]BHF65[/TD]
[TD]BHF73954[/TD]
[TD="align: center"]3[/TD]
[/TR]
[TR]
[TD="align: center"]13[/TD]
[TD]BHF65[/TD]
[TD]BHF73955[/TD]
[TD="align: center"]3[/TD]
[/TR]
[TR]
[TD="align: center"]14
[/TD]
[TD]BHF65[/TD]
[TD]BHF65[/TD]
[TD="align: center"]3[/TD]
[/TR]
</tbody>[/TABLE]


Is this achievable?
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Try this:-
Results start "G1"
NB:- This code will overwrite the Basic data if you require, just change the Range at bottom of code from "G1" to "A1".
Code:
[COLOR=Navy]Sub[/COLOR] MG26Jul35
[COLOR=Navy]Dim[/COLOR] Rng [COLOR=Navy]As[/COLOR] Range, Dn [COLOR=Navy]As[/COLOR] Range, n [COLOR=Navy]As[/COLOR] [COLOR=Navy]Long,[/COLOR] c [COLOR=Navy]As[/COLOR] [COLOR=Navy]Long,[/COLOR] Q [COLOR=Navy]As[/COLOR] Variant, K [COLOR=Navy]As[/COLOR] Variant
[COLOR=Navy]Set[/COLOR] Rng = Range(Range("A2"), 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, Array(Dn, 1)
    [COLOR=Navy]Else[/COLOR]
        Q = .Item(Dn.Value)
        Q(1) = Q(1) + 1
        .Item(Dn.Value) = Q
    [COLOR=Navy]End[/COLOR] If
[COLOR=Navy]Next[/COLOR]
ReDim ray(1 To Rng.Count * 2, 1 To 3)
ray(1, 1) = "style": ray(1, 2) = "sku": ray(1, 3) = "sku_to_style_count"
c = 1
[COLOR=Navy]For[/COLOR] [COLOR=Navy]Each[/COLOR] K [COLOR=Navy]In[/COLOR] .keys
    [COLOR=Navy]For[/COLOR] n = 1 To .Item(K)(1)
        c = c + 1
        [COLOR=Navy]If[/COLOR] .Item(K)(1) = 1 [COLOR=Navy]Then[/COLOR]
            ray(c, 1) = .Item(K)(0).Value
            ray(c, 2) = .Item(K)(0).Offset(, 1).Value
            ray(c, 3) = 1
        [COLOR=Navy]Else[/COLOR]
            ray(c, 1) = .Item(K)(0).Value
            ray(c, 2) = .Item(K)(0).Offset(, 1).Value
            ray(c, 3) = .Item(K)(1)
            [COLOR=Navy]If[/COLOR] n = .Item(K)(1) [COLOR=Navy]Then[/COLOR]
                c = c + 1
                ray(c, 1) = .Item(K)(0).Value
                ray(c, 2) = .Item(K)(0).Value
                ray(c, 3) = .Item(K)(1)
            [COLOR=Navy]End[/COLOR] If
        [COLOR=Navy]End[/COLOR] If
    [COLOR=Navy]Next[/COLOR] n
[COLOR=Navy]Next[/COLOR] K
[COLOR=Navy]End[/COLOR] With
[COLOR=Navy]With[/COLOR] Range("G1").Resize(c, 3)
    .Value = ray
    .Columns.AutoFit
    .Borders.Weight = 2
[COLOR=Navy]End[/COLOR] [COLOR=Navy]With[/COLOR]
[COLOR=Navy]End[/COLOR] [COLOR=Navy]Sub[/COLOR]
Regards Mick
 
Upvote 0
Give this macro a try...
Code:
Sub SKU2StyleCount()
  Dim R As Long, LastRow As Long
  LastRow = Cells(Rows.Count, "A").End(xlUp).Row
  Application.ScreenUpdating = False
  With Range("C2:C" & LastRow)
    .Formula = "=COUNTIF(A$2:A$12,A2)"
    .Value = .Value
    For R = LastRow To 2 Step -1
      If Cells(R, "A").Value <> Cells(R + 1, "A").Value And Cells(R, "C").Value > 1 Then
        Rows(R + 1).Insert
        Cells(R + 1, "A").Resize(, 2).Value = Cells(R, "A").Value
        Cells(R + 1, "C").Value = Cells(R, "C").Value
      End If
    Next
  End With
  Application.ScreenUpdating = True
End Sub
 
Upvote 0
The power of expert programmers and Excel always amaze me.

Both macros work perfectly. I am now trying to figure out which one would be faster, running on 25,000 records? Thank you Mick and Rick.
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,333
Members
452,636
Latest member
laura12345

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