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

Formula to only copy cells with values

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


Joined: 09 Apr 2012
Posts: 60

PostPosted: Fri Jul 20, 2012 11:05 pm    Post subject: Formula to only copy cells with values Reply with quote

This one might be easy, but I just have´nt the skills to write it myself.

I have this row with numbers, and some empty cells.
'I need a formula to copy only the cells with values.
I know how to do this while sort the numbers in ascending order, but this time i´ll need to do it without affecting their original order.
Please look at the example below

[11][7][ ][13][56][ ] [ ] [14

The needed formula would give me the following row
[11][7][13][56][14]

Thanks for any answer!
Back to top
View user's profile Send private message
ken johnson
Super User
Super User


Joined: 23 Apr 2009
Posts: 2032
Location: Sydney, Australia

PostPosted: Sat Jul 21, 2012 1:09 am    Post subject: Reply with quote

You could either use a helper row or an array formula.
Say the original numbers and blanks are in A1:G1 and you want the numbers only in row 7 then this helper formula in A6 filled across to G6 returns an indexing value for the columns with numbers...
Code:
=IF(ISNUMBER(A1);COLUMN(A6)-COLUMN($A6)+1;"")

Then this formula in A7 filled across to G7 returns the numbers in their original order...
Code:
=IF(COLUMN(A7)-COLUMN($A6)+1>COUNT($A$1:$G$1);"";INDEX($A$1:$G$1;1;SMALL($A$6:$G$6;COLUMN(A7)-COLUMN($A6)+1)))
See second sheet in attached doc.

If you don't want to use a helper row then this array formula could be used in A7 filled across to G7...
Code:
IF(COLUMN(A7)-COLUMN($A7)+1>COUNT($A$1:$G$1);"";INDEX($A$1:$G$1;1;SMALL(IF(ISNUMBER($A$1:$G$1);COLUMN($A$1:$G$1)-MIN(COLUMN($A$1:$G$1))+1;"");COLUMN(A7)-COLUMN($A7)+1)))
Being an array formula it must be entered using Ctrl+Shift +Enter PC key combination. Also, the Ctrl key must be held down while dragging the fill handle as you fill the formula into adjacent cells.
See first sheet in attached doc.
http://www.mediafire.com/view/?ullkghad2l9dni2

Ken Johnson
_________________
If your problem has been solved please add "[Solved]" to the beginning of your first post title (edit button).


Last edited by ken johnson on Sun Sep 23, 2012 2:57 am; edited 1 time in total
Back to top
View user's profile Send private message
karolus
OOo Advocate
OOo Advocate


Joined: 22 Jun 2011
Posts: 210

PostPosted: Sat Jul 21, 2012 1:24 am    Post subject: Reply with quote

Hallo

Code:
=INDEX(A1:Z1;SMALL(IF(A1:Z1;COLUMN(A1:Z1);"");COLUMN(A1:Z1)))


as Matrixformula
Back to top
View user's profile Send private message
Robert Tucker
Moderator
Moderator


Joined: 16 Aug 2004
Posts: 3407
Location: Manchester UK

PostPosted: Sat Jul 21, 2012 2:33 am    Post subject: Reply with quote

Code:
=INDEX($B$4:$I$4;SMALL(IF(ISBLANK($B$4:$I$4);"";COLUMN($B$4:$I$4)-MIN(COLUMN($B$4:$I$4))+1);COLUMN(B4:I4)-1)) Ctrl+Shift+Enter

http://www.get-digital-help.com/2007/09/16/excel-remove-blank-cells/#array


_________________
OpenOffice 4.0.0 and LibreOffice 4.x.x on Fedora 20, Ubuntu 13.10, Windows 8.1 Preview (Triple Boot)
Back to top
View user's profile Send private message
fivefootnine
Power User
Power User


Joined: 09 Apr 2012
Posts: 60

PostPosted: Sat Jul 21, 2012 3:50 am    Post subject: Reply with quote

Thank you guys! You are the best!!
I´ll see which code that suits my needs the best!! Thank you again!
Problem solved!
Have a nice weekend all of you!
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