Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 6
Default Concatenate with carriage return- how to remove blanks?

I'm trying to concatenate 15+ columns into one and have the results appear in
list format- so I've used =concatenate(a1,char(10),a2,char(10),a3.....
function. Wrap text is enabled. However, some source columns contain blanks
and I don't want a blank row showing (it will make my row height huge!) and
make the list look odd with big blank spaces. Any ideas?

  #2   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 3,718
Default Concatenate with carriage return- how to remove blanks?

Download and install the free add-in Morefunc.xll from:

http://xcell05.free.fr/morefunc/english/index.htm
then use this formula

=SUBSTITUTE(MCONCAT(IF(A1:A15<"",A1:A15&CHAR(10), "")),CHAR(10),"",COUNTA(A1:A15))

ctrl+shift+enter, not just enter


"cindyc" wrote:

I'm trying to concatenate 15+ columns into one and have the results appear in
list format- so I've used =concatenate(a1,char(10),a2,char(10),a3.....
function. Wrap text is enabled. However, some source columns contain blanks
and I don't want a blank row showing (it will make my row height huge!) and
make the list look odd with big blank spaces. Any ideas?

  #3   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 434
Default Concatenate with carriage return- how to remove blanks?

hi, cindy !

I'm trying to concatenate 15+ columns into one and have the results appear in list format-
so I've used =concatenate(a1,char(10),a2,char(10),a3..... function. Wrap text is enabled.
However, some source columns contain blanks and I don't want a blank row showing
(it will make my row height huge!) and make the list look odd with big blank spaces. Any ideas?


you might want to give a try defining your own UDF (in a standard code module) like the following:

Function ConcatenateNonBlanks(Data As Range, _
Optional byColumns As Boolean = False, _
Optional Separator As String = ", ") As String
Dim resValues As Variant
resValues = Evaluate("if(" & Data.Address & "<""""," & Data.Address & ",""|"")")
With Application
ConcatenateNonBlanks = .Substitute(.Substitute( _
Join(IIf(byColumns, .Transpose(.Transpose(resValues)), .Transpose(resValues)), _
Separator), "|" & Separator, ""), Separator & "|", "")
End With
End Function

then, you can use (i.e.) [A1] cell to put your "separator" character (i.e.) =char(10) as the 3rd argument
passing as true/<non cero the second (byColumns) to horizontal concatenate or leave it blank to vertical concatenation
and call the above sample function (i.e.)

=ConcatenateNonBlanks(B1:L1,1,A1)
=ConcatenateNonBlanks(B1:B15,,A1)

hth,
hector.


  #4   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 22,906
Default Concatenate with carriage return- how to remove blanks?

Function ConCatRange(CellBlock As Range) As String
Dim Cell As Range
Dim sbuf As String
For Each Cell In CellBlock
If Len(Cell.text) 0 Then sbuf = sbuf & Cell.text & chr(10)
Next
ConCatRange = Left(sbuf, Len(sbuf) - 1)
End Function

Ignores blank cells.

Usage is =concatrange(A1:A17)


Gord Dibben MS Excel MVP

On Tue, 16 Sep 2008 20:30:00 -0700, cindyc
wrote:

I'm trying to concatenate 15+ columns into one and have the results appear in
list format- so I've used =concatenate(a1,char(10),a2,char(10),a3.....
function. Wrap text is enabled. However, some source columns contain blanks
and I don't want a blank row showing (it will make my row height huge!) and
make the list look odd with big blank spaces. Any ideas?


Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Concatenate and remove blanks PeterW Excel Worksheet Functions 3 January 19th 06 06:04 PM
Concatenate columns with cell data containing Carriage Returns Rob Excel Worksheet Functions 3 October 4th 05 08:49 AM
Concatenate cells with carriage returns Rob Excel Worksheet Functions 1 October 3rd 05 06:25 PM
How to remove or replace a carriage return character in a cell? Patty Excel Discussion (Misc queries) 2 July 26th 05 06:25 PM
How do I remove multiple line feed(s) or carriage return(s)? sra Excel Discussion (Misc queries) 1 May 25th 05 12:02 AM


All times are GMT +1. The time now is 11:23 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"