Reverse Pivot Table?

routeski

New Member
Joined
Jan 20, 2005
Messages
17
Hi guys,
First post so bear with me! I am trying to achieve what I can only describe as a reverse Pivot Table. My example is this:

I have a list of product codes and quanties. eg:

Product Qty
10003 1
100030 1
10004 1
100061 5
10022 1
10041 3
10044 2
10047 1
10054 1
10055 1
10058 1
10064 1

What I want to have is all the quantities to all be 1, and the product to be duplicated as necessary, so the end result will be:

Product Qty
10003 1
100030 1
10004 1
100061 1
100061 1
100061 1
100061 1
100061 1
10022 1
10041 1
10041 1
10041 1
10044 1
10044 1
10047 1
10054 1
10055 1
10058 1
10064 1


Hope this makes sense! Please help! THanks!
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
book1
ABCD
1ProductQtyExpanded
210003110003
31000301100030
410004110004
51000615100061
6100221100061
7100413100061
8100442100061
9100471100061
1010054110022
1110055110041
1210058110041
1310064110041
1410044
1510044
1610047
1710054
1810055
1910058
2010064
21#REF!
22#REF!
23#REF!
24#REF!
Sheet2


D2 is seeded with a hard-coded copy of A2 [of course, you could use a formula like =A2 if you wanted]. Formula in D3 and copied down is:
=IF(COUNTIF(D$2:D2,D2)=INDEX($B$2:$B$13,MATCH(D2,$A$2:$A$13,0)),INDEX($A$2:$A$13,MATCH(D2,$A$2:$A$13,0)+1),D2)

I should note that this solution will fail spectacularly if any product code is repeated in column A.

HTH
 
Upvote 0
Genius! No one at work could do that. How do i extend it if there are like 100 rows with a sum of 40,000 quantities? Which part of the equation do we change?
 
Upvote 0
Just compare the ranges in the formula to the example posted...i.e. <ul>[*]Whereever you see "$B$2:$B13", replace that with the address of the range of your quantities. Note that the reference needs to be an absolute address (the $ signs) [at least for the row #'s] -- or of course you can use a named range if you prefer.[*]Whereever you see "$A$2:$A$13", replace that with the address of the range with your product codes (again, rows must be absolute or use a named range).[*]Whereever you see a reference to D2, change that be the address of the cell with hard-coded product code at the top of your expanded column.<ul>[*]For example: if your expanded column were H and your first, hard-coded product code were in H1, then the arguments for the first CountIf would be CountIf(H$1:H1,H1); the first args for each MATCH() would be H1; and the last arg of the whole formula would be H1.[/list][/list]

Edit - If you're going to end up with 40,000 rows, you may want to break this into smaller chunks. Meaning copy the expansion formula to something like 5,000 rows. Then copy and paste values over the first 4,999 rows. Then copy down another 5,000 rows, paste values for 4,999 and so on -- adjusting this "5,000" up or down depending on how snappy your computer is reacting and crunching through the recalcs.
 
Upvote 0

Forum statistics

Threads
1,214,839
Messages
6,121,892
Members
449,058
Latest member
Guy Boot

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