Concatenate maximum number of parameters

J

Jorge E. Jaramillo

I need to consolidate the results of all the sheets of a workbook in a final
sheet. For this I use the concatenate function. To try to organize the
results, I added a comma in between each value (",",) but since the formula
requires the name of each tab and cell and some of the names of the tabs are
kind of long, I am getting an error message about entering too many
parameters. My workaround was to remove some of the commas at the end of the
formula, and the formula works now this way, but now the results look
difficult to understand.

Could someone please tell me what the limit of parameters is and if is there
a way to solve this?


Jorge E Jaramillo
 
J

JLatham

Excel HELP for Concatenate will tell you the number of parameters limit for
the version you are using. In Excel 2003 it is 30.

But you don't have to use CONCATENATE() to concatenate things! And that
would remove the 30 parameter limit, moving you to the limit for a formula
(1024 characters in 2003).

Consider this example (that concatenates A1 on the sheet with the formula
with C4 from another sheet in the same book, and A7 on Sheet1 in another
workbook, with commas separating each):
=CONCATENATE(A1," , ",Sheet3!C4," , ",[Book2]Sheet1!$A$7)
can be written without CONCATENATE as
=A1 & " , " & Sheet3!C4 & " , " & [Book2]Sheet1!$A$7
with the same results.
 
T

T. Valko

If you used the CONCATENATE function then there's a limit to the number of
arguments which is Excel version dependent. Excel 2007 = 255 arguments, all
other versions = 30 arguments.

You don't need to use the CONCATENATE function. You can use the & operator
to concatenate.

=Sheet1!A1&", "&Sheet2!B20&", "&Sheet5!X101

Using this method you're only limited by the allowable max length for a
formula which, again, is version dependent. Excel 2007 = 8192 characters,
all other versions = 1024 characters.
 
J

Jorge E. Jaramillo

Thank you guys, I used the "&" and it worked.

But now I want to make it even more sophisticated. It is not uncommon that
some of the values are empty, so in the summary cell it is shown: AB1,
XO2,,VA5,,,,LN2 (being AB1, XO2,,VA5,,,,LN2 the contents of the original
cells and not having anything to do with the names of those cells).

Would it be possible to add a condition that if the origin cell is empty,
not to add the comma?

Jorge E Jaramillo
 
G

Gord Dibben

Copy this UDF to a general module in your workbook.

Function ConCatRange(CellBlock As Range) As String
'for non-contiguous cells =ccr((a1:a10,c4,c6,e1:e5))
Dim Cell As Range
Dim sbuf As String
For Each Cell In CellBlock
If Len(Cell.text) > 0 Then sbuf = sbuf & Cell.text & ","
Next
ConCatRange = Left(sbuf, Len(sbuf) - 1)
End Function

It will ignore blank cells.

Usage is =concatrange(range)


Gord Dibben MS Excel MVP
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top