OpenOffice.org Forum at OOoForum.orgThe OpenOffice.org Forum
 
 [Home]   [FAQ]   [Search]   [Memberlist]   [Usergroups]   [Register
 [Profile]   [Log in to check your private messages]   [Log in

convert cells to a text list?

 
Post new topic   Reply to topic    OOoForum.org Forum Index -> OpenOffice.org Calc
View previous topic :: View next topic  
Author Message
acknak
Moderator
Moderator


Joined: 13 Aug 2004
Posts: 4295
Location: ~ 40°N,75°W

PostPosted: Sat Nov 10, 2007 7:48 am    Post subject: convert cells to a text list? Reply with quote

Does anyone have a good way to convert a range of cells to a comma-separated text list of the values?

I'm creating a link with the form url?id=comma-separated-id-list...
E.g. http://www.example.com/articles?id=123,332,724,910

I have the article ids (as text values) in a named range--how do I convert them into the comma-separated list?

Here's what I have now, which frankly sucks:
Code:
=IF(ISBLANK(A4);"";A4) & IF(ISBLANK(A5);"";","&A5) ... & IF(A29="";"";"," & A29)
The list item there picks up a second group of ten ids.

I must be missing something obvious; this is trivial in any modern language. Ideally, there would be a simple function, like this: JOIN( Separator ; Range )

Even better would be something that would take the current selection, but I'm fairly sure that has to be done with a macro, which I would like to avoid if possible.
Back to top
View user's profile Send private message
Villeroy
Super User
Super User


Joined: 04 Oct 2004
Posts: 10106
Location: Germany

PostPosted: Sat Nov 10, 2007 11:02 am    Post subject: Reply with quote

Quote:
this is trivial in any modern language
Spreadsheets did not change very much since late 80s.
Most simple solution I can think of (sorry, it's stupid Basic code):
Code:

Function JOINCOLUMN(values, sep$)
on error goto exitErr
   dim aRow(lBound(values, 1) to uBound(values, 1))
   for i = lBound(aRow()) to uBound(aRow())
      aRow(i) = values(i, 1)
   next
   JOINCOLUMN = Join(aRow(), sep)
exit function
exitErr:
   REM #VALUE
   JOINCOLUMN = Null
End Function

Usage:
=JOINCOLUMN(A1:A9;",") [blanks are "0"]
{=JOINCOLUMN(IF(ISBLANK(A1:A9);"";A1:A9);",")} [blanks are ""]

Joining a horizontal range:
=JOINCOLUMN(TRANSPOSE(A1:X1);",")
Surprisingly, the last one treats blanks as "". THis is due to TRANSPOSE, so we can change the second example (including clause IF(ISBLANK() in array context):
=JOINCOLUMN(TRANSPOSE(TRANSPOSE(A1:A9));",")
Back to top
View user's profile Send private message
RickRandom
Super User
Super User


Joined: 27 Jan 2006
Posts: 1082
Location: UK

PostPosted: Sat Nov 10, 2007 11:25 am    Post subject: Reply with quote

I'd do this by putting the formula in for just 2 cells, then copying/filling as necessary:

Text in cells A5, A6, etc:

In B5:

=A5

In B6:

=B5&","&A6

then fill down as necessary, 3 cells, 30 cells, whatever. The list "grows".

You can add the IF(ISBLANK(... stuff as necessary.
Back to top
View user's profile Send private message
acknak
Moderator
Moderator


Joined: 13 Aug 2004
Posts: 4295
Location: ~ 40°N,75°W

PostPosted: Sat Nov 10, 2007 2:54 pm    Post subject: Reply with quote

Thanks a lot, those are both very helpful suggestions.

I'll see how they work out.
Back to top
View user's profile Send private message
Display posts from previous:   
Post new topic   Reply to topic    OOoForum.org Forum Index -> OpenOffice.org Calc All times are GMT - 8 Hours
Page 1 of 1

 
Jump to:  
You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum
You cannot vote in polls in this forum


Powered by phpBB © 2001, 2005 phpBB Group