Is there a formula that can consolidate the cells of a spilled result, as text, into one cell?

TomCon

Active Member
Joined
Mar 31, 2011
Messages
373
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
This formula
=""&IF($B2:$B14=I$1,$D2:$D14)
Produces this result
6
A
FALSE
FALSE
FALSE
FALSE
FALSE
FALSE
FALSE
FALSE
FALSE
FALSE
FALSE
and copied right, it produces
FALSE
FALSE
2
6
9
T
J
Q
FALSE
FALSE
FALSE
FALSE
FALSE
(its random card hand generation if you recognize it!)

I want the first result to be the text string
"6A"
and the second to be the text string
"269TJQ"

What i would call a "brute-force" formula can do it as follows.
=""&IF(LEN(I7)=1,I7,"")&IF(LEN(I8)=1,I8,"")&IF(LEN(I9)=1,I9,"")&IF(LEN(I10)=1,I10,"")&IF(LEN(I11)=1,I11,"")&IF(LEN(I12)=1,I12,"")&IF(LEN(I13)=1,I13,"")&IF(LEN(I14)=1,I14,"")&IF(LEN(I15)=1,I15,"")&IF(LEN(I16)=1,I16,"")&IF(LEN(I17)=1,I17,"")&IF(LEN(I18)=1,I18,"")&IF(LEN(I19)=1,I19,"")
And it produces "6A" for the first case. But it is very tricky and cumbersome to copy and reproduce the correct result, you have to edit every cell reference to get it right.

I wonder if there is a single, more simplified formula that will do what the above formula does, consolidate the SPILL result into a single text string.

If you can do that, please post the formula!

Thanks!
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
How about
Excel Formula:
=TEXTJOIN("",,IF($B2:$B14=I$1,$D2:$D14,""))
 
Upvote 0
Solution
Thanks much, that does it a nice easy to maintain and copy representation!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,788
Messages
6,121,603
Members
449,038
Latest member
Arbind kumar

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