Combine Row and Column Data

nannerb22

New Member
Joined
Jul 7, 2017
Messages
2
Hello all,

I tried searching for a thread that addresses this question, but I was not able to locate one. I may not have worded my search correctly.

I receive a hospital's accounting trial balance that has hospital department numbers as row headers across the row 1 and account type numbers in column A. What I want to do is the following:

1. Combine each department number with each account type number.
2. Combine each department name with each account type name.
3. Pull the balance where the department number and account type number intersect.

See below for a visual example that is likely easier to understand.

What I receive:
[TABLE="class: grid, width: 500, align: left"]
<tbody>[TR]
[TD][/TD]
[TD][/TD]
[TD]10[/TD]
[TD]20[/TD]
[TD]30[/TD]
[TD]40[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD]Administration[/TD]
[TD]Surgery[/TD]
[TD]Laboratory[/TD]
[TD]Radiology[/TD]
[/TR]
[TR]
[TD]6000[/TD]
[TD]Salaries[/TD]
[TD]200,000[/TD]
[TD]150,000[/TD]
[TD]100,000[/TD]
[TD]75,000[/TD]
[/TR]
[TR]
[TD]7000[/TD]
[TD]FICA Tax[/TD]
[TD]25,000[/TD]
[TD]15,000[/TD]
[TD]10,000[/TD]
[TD]7,500[/TD]
[/TR]
[TR]
[TD]8000[/TD]
[TD]Benefits[/TD]
[TD]10,000[/TD]
[TD]5,000[/TD]
[TD]0[/TD]
[TD]2,000[/TD]
[/TR]
</tbody>[/TABLE]









The result I would like to get to:

[TABLE="class: grid, width: 500, align: left"]
<tbody>[TR]
[TD]Account Number[/TD]
[TD]Account Name[/TD]
[TD]Account Balance[/TD]
[/TR]
[TR]
[TD]10-6000[/TD]
[TD]Administration - Salaries[/TD]
[TD]200,000[/TD]
[/TR]
[TR]
[TD]10-7000[/TD]
[TD]Administration - FICA Taxes[/TD]
[TD]25,000[/TD]
[/TR]
[TR]
[TD]10-8000[/TD]
[TD]Administration - Benefits[/TD]
[TD]10,000[/TD]
[/TR]
[TR]
[TD]20-6000[/TD]
[TD]Surgery - Salaries[/TD]
[TD]150,000[/TD]
[/TR]
[TR]
[TD]20-7000[/TD]
[TD]Surgery - FICA Tax[/TD]
[TD]15,000[/TD]
[/TR]
[TR]
[TD]20-8000[/TD]
[TD]Surgery - Benefits[/TD]
[TD]5,000[/TD]
[/TR]
[TR]
[TD]30-6000[/TD]
[TD]Laboratory - Salaries[/TD]
[TD]100,000[/TD]
[/TR]
[TR]
[TD]30-7000[/TD]
[TD]Laboratory - FICA Tax[/TD]
[TD]10,000[/TD]
[/TR]
[TR]
[TD]30-8000[/TD]
[TD]Laboratory - Benefits[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]40-6000[/TD]
[TD]Radiology - Salaries[/TD]
[TD]75,000[/TD]
[/TR]
[TR]
[TD]40-7000[/TD]
[TD]Radiology - FICA Tax[/TD]
[TD]7,500[/TD]
[/TR]
[TR]
[TD]40-8000[/TD]
[TD]Radiology - Benefits[/TD]
[TD]2,000[/TD]
[/TR]
</tbody>[/TABLE]






















I'm trying to find the least time consuming way to get to the end result above. I would be open to solutions using formulas, VBA (very little experience, but will work with this if there is a solution using VBA), or Power Query.

OS: Windows 7
Excel : Excel 2010 with Power Query Addin installed

Thank you.
Brennan
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
Try this for results on sheet2.
NB:- I have assumed that the first "Salary", "6000" start in "A3".
Code:
[COLOR=navy]Sub[/COLOR] MG13Jan27
[COLOR=navy]Dim[/COLOR] Ray [COLOR=navy]As[/COLOR] Variant, ac [COLOR=navy]As[/COLOR] [COLOR=navy]Long,[/COLOR] n [COLOR=navy]As[/COLOR] [COLOR=navy]Long,[/COLOR] c [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
Ray = Range("C1").CurrentRegion
ReDim nray(1 To UBound(Ray, 1) * UBound(Ray, 2), 1 To 3)
nray(1, 1) = "Account Number": nray(1, 2) = "Account Name": nray(1, 3) = "Account Balance"
c = 1
[COLOR=navy]For[/COLOR] ac = 3 To UBound(Ray, 2)
   [COLOR=navy]For[/COLOR] n = 3 To UBound(Ray, 1)
        c = c + 1
        nray(c, 1) = Format(Ray(1, ac) & "_" & Ray(n, 1), "@")
        nray(c, 2) = Ray(2, ac) & "_" & Ray(n, 2)
        nray(c, 3) = Ray(n, ac)
    [COLOR=navy]Next[/COLOR] n
[COLOR=navy]Next[/COLOR] ac
[COLOR=navy]With[/COLOR] Sheets("Sheet2").Range("A1").Resize(c, 3)
    .Value = nray
    .Borders.Weight = 2
    .Columns.AutoFit
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,162
Messages
6,170,431
Members
452,326
Latest member
johnshaji

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