Reformat Data based on Multiple Unique Values for fixed List

hassanleo1987

Board Regular
Joined
Apr 19, 2017
Messages
56
Hi,

I have a large data set of multiple columns (maximum 10) and rows more than 50K.
The data set has 2 parts.
1st part included a single column of unique values (alpha-numeric) only. let call it IDs
2nd part is a table where unique values from part 1 are linked together with 2 separate values which we'll call left and right.
The linkup is called 2-way relationship, which means IDs will have 2 types of values, one of right side and one on left side. When looking for unique values on the right side, the ID value will be filters from left column and vice versa.
There are duplications of data when filtering this way but they are ignored.

I need to get this list sorted in a way the for every ID value from part 1, there will be 2 side of table where unique values of right and left column are listed. The number of values on left and right are variable so which ever value is maximum, will determine the number of rows needed for each ID. While looking up unique left and right values, the 2 Value columns i.e., Value 1 and Value 2 will be looked up for both sides.

Final step is to apply formatting, each unique ID along with its left, right and values should be in a single border box to identify as unique set.

Currently I am all these steps using arrays, which takes a lot of time and I have to do it in multiple parts.

Is there a way, this could be done using VBA where I can specify the ID column, Left, right and value columns and the code will sort the data in the required format.

Please if somebody can help!
 
One more question:
Some items exist in the Data but not in unique values, such as G,H,I..etc.
So it's possible that some items exist in the Data but not in unique values?
 
Upvote 0

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
One more question:
Some items exist in the Data but not in unique values, such as G,H,I..etc.
So it's possible that some items exist in the Data but not in unique values?
I just realize a mistake I make with unique value list. That list should contain all values uptill S as can be seen in data table. Actually when I made that example data set. I just isolated 6 unique value to show the complete set of relationships of those only. All other values shown in data table should also be part of unique values.

In conclusion, all unique values in right and left column are part of unique ID set but just for the seek of showing 6 complete sets, i didn't include them in unique ID list.

Sorry for the confusion.
 
Upvote 0
One more question:
Some items exist in the Data but not in unique values, such as G,H,I..etc.
So it's possible that some items exist in the Data but not in unique values?
This example should have been like this!

Complete left and right relationship for 6 IDs A ~ F and remaining ID should also be part of unique list.

Example.xlsx
ABCDEFGHIJKLMNOPQ
1
2Data:Result:
3UniqueLeftRightValue 1Value 2Value 1Value 2LeftUniqueRightValue 1Value 2
4ACE1001GAC10
5BFK240    
6CCD1001IBC240
7DDL10    
8ECM12501ACE10
9FFN325402BCD10
10GAC10  CM125
11HDO250    
12IEF1001CDL10
13JBC240  DO250
14KDP10  DP10
15LFQ225    
16MFR22501CEF10
17NFS1001HE  
18OCD10    
19PGA1001HFK240
20QAC1001EFN325
21RHE1003JFQ225
22SHF10  FR225
23EF10  FS10
24BC240    
25IB10
26JF30
27
Data
Cell Formulas
RangeFormula
J4:J24J4=IFERROR(INDEX(Data!$G$4:$G$26,MATCH(1,($M4=Data!$E$4:$E$26)*($L4=Data!$D$4:$D$26),0)),"")
K4:K24K4=IFERROR(INDEX(Data!$F$4:$F$26,MATCH(1,($M4=Data!$E$4:$E$26)*($L4=Data!$D$4:$D$26),0)),"")
O4:O24O4=IFERROR(INDEX(Data!$F$4:$F$26,MATCH(1,($M4=Data!$D$4:$D$26)*($N4=Data!$E$4:$E$26),0)),"")
P4:P24P4=IFERROR(INDEX(Data!$G$4:$G$26,MATCH(1,($M4=Data!$D$4:$D$26)*($N4=Data!$E$4:$E$26),0)),"")
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Try this:
1. To make it easier to code & make it faster I set up the result in ascending order. You see in cell L9:L20, the result show different order than your example. Is it a problem?
2. I commented this part:
'to set cells borders, it could slow down the code significantly
'With Range(Cells(w + 4, "J"), Cells(ww + 2, "P"))
' .Borders(xlEdgeLeft).LineStyle = xlContinuous
' .Borders(xlEdgeRight).LineStyle = xlContinuous
' .Borders(xlEdgeBottom).LineStyle = xlContinuous
' .Borders(xlEdgeTop).LineStyle = xlContinuous
'End With

it is to format cells borders, it could slow down the code significantly. So test it without formatting the borders first on your original data.

VBA Code:
Option Explicit
Sub hassanleo1987a()
Dim i As Long, j As Long, k As Long, m As Long, n As Long, w As Long, ww As Long
Dim u As Long, q As Long, p As Long
Dim va, vb, vc, vd, vx, vz, t, vcx, vdx, x, fm
Dim c As Range
t = Timer
Application.EnableEvents = False
Application.ScreenUpdating = False
With Range("b3", Cells(Rows.Count, "B").End(xlUp))
.Sort Key1:=.Cells(1), Order1:=xlAscending, Header:=xlYes
End With

vx = Application.Transpose(Range("b4", Cells(Rows.Count, "b").End(xlUp)))

va = Range("d3", Cells(Rows.Count, "d").End(xlUp)).Resize(, 4)

Set c = Range("z3").Resize(UBound(va, 1), 4)
c = va
c.Sort Key1:=c.Cells(1, 2), Order1:=xlAscending, Key2:=c.Cells(1, 1), Order2:=xlAscending, Header:=xlYes
vb = c: c = va
c.Sort Key1:=c.Cells(1, 1), Order1:=xlAscending, Key2:=c.Cells(1, 2), Order2:=xlAscending, Header:=xlYes
va = c
c.ClearContents


ReDim vc(1 To UBound(va, 1), 1 To 4)
ReDim vd(1 To UBound(va, 1), 1 To 4)

For i = 2 To UBound(va, 1)
    j = i
        Do
            i = i + 1
            If i > UBound(va, 1) Then Exit Do
        Loop While va(i, 1) = va(i - 1, 1)
        i = i - 1
        
        For k = j To i
            n = n + 1
            For m = 1 To 4
                If k > j And va(k, 2) = va(k - 1, 2) Then n = n - 1: Exit For
                vc(n, m) = va(k, m)
            Next
        Next
Next

n = 0
For i = 2 To UBound(vb, 1)
    j = i
        Do
            i = i + 1
            If i > UBound(vb, 1) Then Exit Do
        Loop While vb(i, 1) = vb(i - 1, 1)
        i = i - 1
        
        For k = j To i
            n = n + 1
            For m = 1 To 4
                If k > j And vb(k, 2) = vb(k - 1, 2) Then n = n - 1: Exit For
                vd(n, m) = vb(k, m)
            Next
        Next
Next

'clear cells border
With Range("J:P")
    .Borders(xlDiagonalDown).LineStyle = xlNone
    .Borders(xlDiagonalUp).LineStyle = xlNone
    .Borders(xlEdgeLeft).LineStyle = xlNone
    .Borders(xlEdgeTop).LineStyle = xlNone
    .Borders(xlEdgeBottom).LineStyle = xlNone
    .Borders(xlEdgeRight).LineStyle = xlNone
    .Borders(xlInsideVertical).LineStyle = xlNone
    .Borders(xlInsideHorizontal).LineStyle = xlNone
End With

ReDim vz(1 To UBound(va, 1) + UBound(vb), 1 To 7)
vcx = Application.Index(vc, , 1)
vdx = Application.Index(vd, , 2)

For Each x In vx
fm = Application.Match(x, vcx, 0)
    If IsNumeric(fm) Then
        u = w + 1
        Do
            u = u + 1
            vz(u, 4) = vc(fm, 1)
            vz(u, 5) = vc(fm, 2)
            vz(u, 6) = vc(fm, 3)
            vz(u, 7) = vc(fm, 4)
            fm = fm + 1
        Loop While vc(fm, 1) = x
        p = u
    End If

fm = Application.Match(x, vdx, 0)
    If IsNumeric(fm) Then
        u = w + 1
        Do
            u = u + 1
            vz(u, 4) = vd(fm, 2)
            vz(u, 3) = vd(fm, 1)
            vz(u, 2) = vd(fm, 3)
            vz(u, 1) = vd(fm, 4)
            fm = fm + 1
        Loop While vd(fm, 2) = x
        q = u
    End If

If p > q Then ww = p Else ww = q

'=====================================
'to format cells borders, it could slow down the code significantly
'With Range(Cells(w + 4, "J"), Cells(ww + 2, "P"))
' .Borders(xlEdgeLeft).LineStyle = xlContinuous
' .Borders(xlEdgeRight).LineStyle = xlContinuous
' .Borders(xlEdgeBottom).LineStyle = xlContinuous
' .Borders(xlEdgeTop).LineStyle = xlContinuous
'End With
'======================================

w = ww
Next

Range("J3").Resize(UBound(vz, 1), 7) = vz
Application.EnableEvents = True
Application.ScreenUpdating = True
Debug.Print "It's done in: " & Timer - t & " seconds"
End Sub

hassanleo1987 - Reformat Data 1.xlsm
JKLMNOP
3
401GAC10
5
601IBC240
7
801ACD10
9402BCE10
10CM125
11
1201CDL10
13DO250
14DP10
15
1601CEF10
1701HE
18
1901EFK240
2001HFN325
2103JFQ225
22FR225
23FS10
24
25GA10
26
27HE10
28HF10
29
30IB10
31
32JF30
33
34402FK
35
3601DL
37
38251CM
39
40253FN
41
42502DO
43
4401DP
45
46252FQ
47
48252FR
49
5001FS
Data
 
Upvote 0
Solution
Try this:
1. To make it easier to code & make it faster I set up the result in ascending order. You see in cell L9:L20, the result show different order than your example. Is it a problem?
2. I commented this part:
'to set cells borders, it could slow down the code significantly
'With Range(Cells(w + 4, "J"), Cells(ww + 2, "P"))
' .Borders(xlEdgeLeft).LineStyle = xlContinuous
' .Borders(xlEdgeRight).LineStyle = xlContinuous
' .Borders(xlEdgeBottom).LineStyle = xlContinuous
' .Borders(xlEdgeTop).LineStyle = xlContinuous
'End With

it is to format cells borders, it could slow down the code significantly. So test it without formatting the borders first on your original data.

VBA Code:
Option Explicit
Sub hassanleo1987a()
Dim i As Long, j As Long, k As Long, m As Long, n As Long, w As Long, ww As Long
Dim u As Long, q As Long, p As Long
Dim va, vb, vc, vd, vx, vz, t, vcx, vdx, x, fm
Dim c As Range
t = Timer
Application.EnableEvents = False
Application.ScreenUpdating = False
With Range("b3", Cells(Rows.Count, "B").End(xlUp))
.Sort Key1:=.Cells(1), Order1:=xlAscending, Header:=xlYes
End With

vx = Application.Transpose(Range("b4", Cells(Rows.Count, "b").End(xlUp)))

va = Range("d3", Cells(Rows.Count, "d").End(xlUp)).Resize(, 4)

Set c = Range("z3").Resize(UBound(va, 1), 4)
c = va
c.Sort Key1:=c.Cells(1, 2), Order1:=xlAscending, Key2:=c.Cells(1, 1), Order2:=xlAscending, Header:=xlYes
vb = c: c = va
c.Sort Key1:=c.Cells(1, 1), Order1:=xlAscending, Key2:=c.Cells(1, 2), Order2:=xlAscending, Header:=xlYes
va = c
c.ClearContents


ReDim vc(1 To UBound(va, 1), 1 To 4)
ReDim vd(1 To UBound(va, 1), 1 To 4)

For i = 2 To UBound(va, 1)
    j = i
        Do
            i = i + 1
            If i > UBound(va, 1) Then Exit Do
        Loop While va(i, 1) = va(i - 1, 1)
        i = i - 1
      
        For k = j To i
            n = n + 1
            For m = 1 To 4
                If k > j And va(k, 2) = va(k - 1, 2) Then n = n - 1: Exit For
                vc(n, m) = va(k, m)
            Next
        Next
Next

n = 0
For i = 2 To UBound(vb, 1)
    j = i
        Do
            i = i + 1
            If i > UBound(vb, 1) Then Exit Do
        Loop While vb(i, 1) = vb(i - 1, 1)
        i = i - 1
      
        For k = j To i
            n = n + 1
            For m = 1 To 4
                If k > j And vb(k, 2) = vb(k - 1, 2) Then n = n - 1: Exit For
                vd(n, m) = vb(k, m)
            Next
        Next
Next

'clear cells border
With Range("J:P")
    .Borders(xlDiagonalDown).LineStyle = xlNone
    .Borders(xlDiagonalUp).LineStyle = xlNone
    .Borders(xlEdgeLeft).LineStyle = xlNone
    .Borders(xlEdgeTop).LineStyle = xlNone
    .Borders(xlEdgeBottom).LineStyle = xlNone
    .Borders(xlEdgeRight).LineStyle = xlNone
    .Borders(xlInsideVertical).LineStyle = xlNone
    .Borders(xlInsideHorizontal).LineStyle = xlNone
End With

ReDim vz(1 To UBound(va, 1) + UBound(vb), 1 To 7)
vcx = Application.Index(vc, , 1)
vdx = Application.Index(vd, , 2)

For Each x In vx
fm = Application.Match(x, vcx, 0)
    If IsNumeric(fm) Then
        u = w + 1
        Do
            u = u + 1
            vz(u, 4) = vc(fm, 1)
            vz(u, 5) = vc(fm, 2)
            vz(u, 6) = vc(fm, 3)
            vz(u, 7) = vc(fm, 4)
            fm = fm + 1
        Loop While vc(fm, 1) = x
        p = u
    End If

fm = Application.Match(x, vdx, 0)
    If IsNumeric(fm) Then
        u = w + 1
        Do
            u = u + 1
            vz(u, 4) = vd(fm, 2)
            vz(u, 3) = vd(fm, 1)
            vz(u, 2) = vd(fm, 3)
            vz(u, 1) = vd(fm, 4)
            fm = fm + 1
        Loop While vd(fm, 2) = x
        q = u
    End If

If p > q Then ww = p Else ww = q

'=====================================
'to format cells borders, it could slow down the code significantly
'With Range(Cells(w + 4, "J"), Cells(ww + 2, "P"))
' .Borders(xlEdgeLeft).LineStyle = xlContinuous
' .Borders(xlEdgeRight).LineStyle = xlContinuous
' .Borders(xlEdgeBottom).LineStyle = xlContinuous
' .Borders(xlEdgeTop).LineStyle = xlContinuous
'End With
'======================================

w = ww
Next

Range("J3").Resize(UBound(vz, 1), 7) = vz
Application.EnableEvents = True
Application.ScreenUpdating = True
Debug.Print "It's done in: " & Timer - t & " seconds"
End Sub

hassanleo1987 - Reformat Data 1.xlsm
JKLMNOP
3
401GAC10
5
601IBC240
7
801ACD10
9402BCE10
10CM125
11
1201CDL10
13DO250
14DP10
15
1601CEF10
1701HE
18
1901EFK240
2001HFN325
2103JFQ225
22FR225
23FS10
24
25GA10
26
27HE10
28HF10
29
30IB10
31
32JF30
33
34402FK
35
3601DL
37
38251CM
39
40253FN
41
42502DO
43
4401DP
45
46252FQ
47
48252FR
49
5001FS
Data
I have tried it both way, with and without cell border portion. Both are working great. With border code, it took around 4 minutes to process the data set with required group borders.

@Akuini You are the best! Thanks a lot for your time and help!

It took me 4 days from extraction to data transformation in this format using just the formulations! I am more than happy with 4 minutes.

Again, appreciate your help with my unique problems!!! ????
 
Upvote 0
You're welcome, glad to help & thanks for the feedback.:)
 
Upvote 0

Forum statistics

Threads
1,215,831
Messages
6,127,146
Members
449,364
Latest member
AlienSx

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