Continuous column array from a non-complete 2d matrix array

learjsy

New Member
Joined
Feb 16, 2018
Messages
12
I have a 2d-matrix array but not all cells contain data. I need a formula to map all of the non-blank data to a continuous column (by rows of the matrix).

I found the following online, which works perfectly except the output includes the blanks from the source matrix: OFFSET(Matrix,TRUNC((ROW()-ROW($BF$5))/COLUMNS(Matrix)),MOD(ROW()-ROW($BF$5),COLUMNS(Matrix)),1,1).

This website appeared to offer a solution to removing the blanks, but I couldn't get it to work with my output above. https://www.myonlinetraininghub.com/excel-remove-blank-cells-from-a-range

Ideally I'd like to do the mapping in one go, but I guess a second step (converting to a column, then removing blanks) would work too.

Thanks in advance
 

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
For future reference / anyone looking for an answer with a similar issue:

I solved this eventually using a combination of a two step-solution (similar to the above) and an elimination sequence to determine what was going wrong.

The first step - using OFFSET(Matrix,TRUNC((ROW()-ROW($BF$5))/COLUMNS(Matrix)),MOD(ROW()-ROW($BF$5),COLUMNS(Matrix)),1,1) - worked perfectly for mapping the 2d (non-complete) array into a single column. The issue was the second step above - IFERROR(INDEX($BF$5:$BF$50,SMALL(IF(ISTEXT($BF$5:$BF$50),ROW($BF$1:$BF$46),""),ROW(BF1))),"") - which should have removed my blanks to create a continuous column.

The issue was that my 'blanks' weren't really blanks - they were zero length strings. Using the following formula in place of step 2 cracked the problem: IFERROR(INDEX($BF$5:$BF$50,SMALL(IF(LEN($BF$5:$BF$50)=0,"",ROW($BF$5:$BF$50)-MIN(ROW($BF$5:$BF$50))+1),ROW(BF1))),"")
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,024
Members
448,543
Latest member
MartinLarkin

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