Converting Vertical data to Selected Horizontal data

Jwgnwa

New Member
Joined
May 20, 2019
Messages
8
Hi All...I am certainly not a master VBA'r, and I cannot find a way to solve the following problem.

I start with a 2 column data set of varying lengths. Column A has Product codes and Column B has Product information. One of the codes is "PN" in column A, this "PN" indicates the start of a new Part Number. The rows following this "PN" have information relating to that Part Number. The number of rows vary depending on the part. Then when the row after the first "PN" has code "PN" this begins a new part number and information so on and so on until there is a blank row. There could be 3 parts or 1,000 parts and the length of the initial 2 column dataset could be 10 rows or 10,000

[TABLE="class: outer_border, width: 100, align: center"]
<tbody>[TR]
[TD="align: center"]Column A[/TD]
[TD="align: center"]Column B[/TD]
[/TR]
[TR]
[TD]PN[/TD]
[TD]12345[/TD]
[/TR]
[TR]
[TD]PD[/TD]
[TD]Desk[/TD]
[/TR]
[TR]
[TD]SP[/TD]
[TD]100.00[/TD]
[/TR]
[TR]
[TD]BP[/TD]
[TD]75.00[/TD]
[/TR]
[TR]
[TD]QT[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]OB[/TD]
[TD]87[/TD]
[/TR]
[TR]
[TD]WT[/TD]
[TD]75[/TD]
[/TR]
[TR]
[TD]PN[/TD]
[TD]98765[/TD]
[/TR]
[TR]
[TD]PD[/TD]
[TD]Shelf[/TD]
[/TR]
[TR]
[TD]BP[/TD]
[TD]35.00[/TD]
[/TR]
[TR]
[TD]MC[/TD]
[TD]R101[/TD]
[/TR]
[TR]
[TD]PN[/TD]
[TD]99999[/TD]
[/TR]
[TR]
[TD]PD[/TD]
[TD]Part[/TD]
[/TR]
[TR]
[TD]QT[/TD]
[TD]4[/TD]
[/TR]
</tbody>[/TABLE]

Now the problem is that I need to copy each part number and the following required part information for that part number (Just the data from Column B) onto rows in Sheet 2. Sheet 2 is laid out with each required code on the columns as headers for the data. (If Column A on the vertical dataset has a code that is not shown as headers on Sheet 2, the data is not needed and not copied to Sheet 2)So the data for the codes must be copied into the correct column header in Sheet 2. Every Part will have a PN (Part Number) and a PD (Part Description)

[TABLE="class: grid, width: 100, align: center"]
<tbody>[TR]
[TD="align: center"]PN[/TD]
[TD="align: center"]PD[/TD]
[TD="align: center"]SP[/TD]
[TD="align: center"]QT[/TD]
[TD="align: center"]SP[/TD]
[TD="align: center"]BP[/TD]
[TD="align: center"]MG[/TD]
[TD="align: center"]OL[/TD]
[TD="align: center"]MC[/TD]
[TD="align: center"]DT[/TD]
[/TR]
[TR]
[TD]12345[/TD]
[TD]Desk[/TD]
[TD]100.00[/TD]
[TD]2[/TD]
[TD][/TD]
[TD]70.00[/TD]
[TD][/TD]
[TD]Oak[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]98765[/TD]
[TD]Shelf[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]35.00[/TD]
[TD][/TD]
[TD][/TD]
[TD]R101[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]99999[/TD]
[TD]Part[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[TD]ETC.[/TD]
[/TR]
</tbody>[/TABLE]


I need to have each part number laid out horizontally so that I can import the data for all the parts into QuickBooks.

I have exhausted my limited VBA knowledge after trying to solve this for weeks. I am hoping this is a simple problem and I am just not seeing it. Thanks for your help
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
You show two columns in your desired output with the header text "SP"... I am assuming the second one it mislabeled, so what should it really be?
 
Upvote 0
with Power Query, just for fun :)
this is not vba!

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]Code[/td][td=bgcolor:#5B9BD5]Value[/td][td][/td][td=bgcolor:#70AD47]PN[/td][td=bgcolor:#70AD47]PD[/td][td=bgcolor:#70AD47]SP[/td][td=bgcolor:#70AD47]BP[/td][td=bgcolor:#70AD47]QT[/td][td=bgcolor:#70AD47]OB[/td][td=bgcolor:#70AD47]WT[/td][td=bgcolor:#70AD47]MC[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]PN[/td][td=bgcolor:#DDEBF7]
12345​
[/td][td][/td][td=bgcolor:#E2EFDA]12345[/td][td=bgcolor:#E2EFDA]Desk[/td][td=bgcolor:#E2EFDA]100[/td][td=bgcolor:#E2EFDA]75[/td][td=bgcolor:#E2EFDA]2[/td][td=bgcolor:#E2EFDA]87[/td][td=bgcolor:#E2EFDA]75[/td][td=bgcolor:#E2EFDA]R101[/td][/tr]

[tr=bgcolor:#FFFFFF][td]PD[/td][td]Desk[/td][td][/td][td]98765[/td][td]Shelf[/td][td][/td][td]35[/td][td]4[/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]SP[/td][td=bgcolor:#DDEBF7]
100​
[/td][td][/td][td=bgcolor:#E2EFDA]99999[/td][td=bgcolor:#E2EFDA]Part[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][/tr]

[tr=bgcolor:#FFFFFF][td]BP[/td][td]
75​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]QT[/td][td=bgcolor:#DDEBF7]
2​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]OB[/td][td]
87​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]WT[/td][td=bgcolor:#DDEBF7]
75​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]PN[/td][td]
98765​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]PD[/td][td=bgcolor:#DDEBF7]Shelf[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]BP[/td][td]
35​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]MC[/td][td=bgcolor:#DDEBF7]R101[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]PN[/td][td]
99999​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]PD[/td][td=bgcolor:#DDEBF7]Part[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]QT[/td][td]
4​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"Code", type text}, {"Value", type text}}),
    Group = Table.Group(Type, {"Code"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "Value", each Table.Column([Count],"Value")),
    Extract = Table.TransformColumns(List, {"Value", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    Rem = Table.RemoveColumns(Extract,{"Count"}),
    Split = Table.SplitColumn(Rem, "Value", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.1", "Value.2", "Value.3"}),
    Demote = Table.DemoteHeaders(Split),
    Transpose = Table.Transpose(Demote),
    Promote = Table.PromoteHeaders(Transpose, [PromoteAllScalars=true]),
    Rem2 = Table.RemoveColumns(Promote,{"Code"})
in
    Rem2[/SIZE]
 
Upvote 0
ignore post above, correct result is here:

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]Code[/td][td=bgcolor:#5B9BD5]Value[/td][td][/td][td=bgcolor:#70AD47]PN[/td][td=bgcolor:#70AD47]PD[/td][td=bgcolor:#70AD47]SP[/td][td=bgcolor:#70AD47]BP[/td][td=bgcolor:#70AD47]QT[/td][td=bgcolor:#70AD47]OB[/td][td=bgcolor:#70AD47]WT[/td][td=bgcolor:#70AD47]MC[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]PN[/td][td=bgcolor:#DDEBF7]
12345​
[/td][td][/td][td=bgcolor:#E2EFDA]12345[/td][td=bgcolor:#E2EFDA]Desk[/td][td=bgcolor:#E2EFDA]100[/td][td=bgcolor:#E2EFDA]75[/td][td=bgcolor:#E2EFDA]2[/td][td=bgcolor:#E2EFDA]87[/td][td=bgcolor:#E2EFDA]75[/td][td=bgcolor:#E2EFDA][/td][/tr]

[tr=bgcolor:#FFFFFF][td]PD[/td][td]Desk[/td][td][/td][td]98765[/td][td]Shelf[/td][td][/td][td]35[/td][td][/td][td][/td][td][/td][td]R101[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]SP[/td][td=bgcolor:#DDEBF7]
100​
[/td][td][/td][td=bgcolor:#E2EFDA]99999[/td][td=bgcolor:#E2EFDA]Part[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA]4[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][/tr]

[tr=bgcolor:#FFFFFF][td]BP[/td][td]
75​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]QT[/td][td=bgcolor:#DDEBF7]
2​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]OB[/td][td]
87​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]WT[/td][td=bgcolor:#DDEBF7]
75​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]PN[/td][td]
98765​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]PD[/td][td=bgcolor:#DDEBF7]Shelf[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]BP[/td][td]
35​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]MC[/td][td=bgcolor:#DDEBF7]R101[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]PN[/td][td]
99999​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]PD[/td][td=bgcolor:#DDEBF7]Part[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]QT[/td][td]
4​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"Code", type text}, {"Value", type text}}),
    Condition = Table.AddColumn(Type, "PN", each if [PLAIN][Code][/PLAIN] = "PN" then [Value] else null),
    FillD = Table.FillDown(Condition,{"PN"}),
    Filter = Table.SelectRows(FillD, each ([PLAIN][Code][/PLAIN] <> "PN")),
    Group = Table.Group(Filter, {"Code", "PN"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "Value", each Table.Column([Count],"Value")),
    Extract = Table.TransformColumns(List, {"Value", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    Rem = Table.RemoveColumns(Extract,{"Count"}),
    Pivot = Table.Pivot(Rem, List.Distinct(Rem[PLAIN][Code][/PLAIN]), "Code", "Value")
in
    Pivot[/SIZE]
 
Last edited:
Upvote 0
See if this does what you want. Check the sheets names are correct and test in a copy of your workbook.
Code:
Sub Parts_List()
  Dim aData As Variant, aResults As Variant, aProdInfo As Variant
  Dim cols As Long, rws As Long, parts As Long, i As Long, k As Long, col As Long
  
  With Sheets("Sheet2")
    cols = .Cells(1, .Columns.Count).End(xlToLeft).Column
    aProdInfo = .Range("A1").Resize(, cols).Value
  End With
  With Sheets("Sheet1")
    aData = .Range("A1", .Range("B" & .Rows.Count).End(xlUp)).Value
    rws = UBound(aData)
    parts = Evaluate("countif('" & .Name & "'!A1:A" & rws & ",""PN"")")
  End With
  If parts > 0 Then
    ReDim aResults(1 To parts, 1 To cols)
    For i = 2 To rws
      If aData(i, 1) = "PN" Then
        k = k + 1
        aResults(k, 1) = aData(i, 2)
      Else
        col = 0
        On Error Resume Next
        col = Application.Match(aData(i, 1), aProdInfo, 0)
        On Error GoTo 0
        If col > 0 Then aResults(k, col) = aData(i, 2)
      End If
    Next i
    Sheets("Sheet2").Range("A2").Resize(k, cols).Value = aResults
  End If
End Sub
 
Upvote 0
It's awesome...Still amazing to find people that are willing to help other people that they don't know, just because they can. Thanks for that.
 
Upvote 0
It's awesome...Still amazing to find people that are willing to help other people that they don't know, just because they can. Thanks for that.
Given your other post that was addressed to Sandy, I'm wondering if this comment was in relation to my suggestion? If so, you are very welcome. If not, you are still very welcome. :biggrin:
 
Upvote 0

Forum statistics

Threads
1,223,727
Messages
6,174,146
Members
452,547
Latest member
Schilling

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