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

[Solved]Conditional formatting if value is found in 2 sheets

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


Joined: 07 Apr 2011
Posts: 3

PostPosted: Thu Apr 07, 2011 2:38 pm    Post subject: [Solved]Conditional formatting if value is found in 2 sheets Reply with quote

Thank you in advance to whoever helps me out with this.

I have a three sheet document that I am trying to format a cell if the current cell contents is found between the other two sheets.

I hope I explained that correctly.

I have a data sheet that contains all of my product information from the other two sheets.
I want my product number to change background color based on the sheet it was found in.

Basically from a programming standpoint it would be.

IF <CURRENT CELL> is found in Sheet1.A40:A300
THEN SET BACKGROUND TO STYLE1
ELSE IF <CURRENT CELL> is found in Sheet2.A40:A300
THEN SET BACKGROUND TO STYLE2
ELSE SET BACKGROUND TO STYLE3

I know it seems easy to do from a programming standpoint, I just haven't been able to wrap my head around the right formulas to use in Calc.

Any help would be much appreciated.
_________________
If we spend so much time reinventing the wheel, how much time will we have left to drive the car?


Last edited by laneh on Thu Apr 07, 2011 7:14 pm; edited 1 time in total
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: Thu Apr 07, 2011 4:51 pm    Post subject: Reply with quote

Try...
Say after selecting all of the cells that are to have the conditional formatting that the active cell is A1000 (the active cell in the selection is the one with the thick black border), then using "Formula is"...
For "Condition 1" use the expression...
Code:
ISNUMBER(MATCH($A1000;$Sheet1.$A$40:$A$300;0))

For "Condition 2" use the expression...
Code:
ISNUMBER(MATCH($A1000;$Sheet2.$A$40:$A$300;0))

and for "Condition 3" use the expression...
Code:
$A1000<>""


Ken Johnson
_________________
If your problem has been solved please add "[Solved]" to the beginning of your first post title (edit button).
Back to top
View user's profile Send private message
laneh
Newbie
Newbie


Joined: 07 Apr 2011
Posts: 3

PostPosted: Thu Apr 07, 2011 6:08 pm    Post subject: Almost got it Reply with quote

Thank you for the quick reply. Almost got it, I just need to see if there is a match in both sheets at the same time for condition 3. Seeing if I can come up with an elaborate IF MATCH statement.
_________________
If we spend so much time reinventing the wheel, how much time will we have left to drive the car?
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: Thu Apr 07, 2011 7:09 pm    Post subject: Re: Almost got it Reply with quote

laneh wrote:
Thank you for the quick reply. Almost got it, I just need to see if there is a match in both sheets at the same time for condition 3. Seeing if I can come up with an elaborate IF MATCH statement.

I think the simple solution is to re-order your tests...
First test for match on both sheets at once with
Code:
AND(ISNUMBER(MATCH($A1000;$Sheet1.$A$40:$A$300;0));ISNUMBER(MATCH($A1000;$Sheet2.$A$40:$A$300;0)))
for Style3
Then test for match on Sheet1 with
Code:
ISNUMBER(MATCH($A1000;$Sheet1.$A$40:$A$300;0))
for Style1
Then test for match on Sheet2 with
Code:
ISNUMBER(MATCH($A1000;$Sheet2.$A$40:$A$300;0))
for Style2

Ken Johnson
_________________
If your problem has been solved please add "[Solved]" to the beginning of your first post title (edit button).
Back to top
View user's profile Send private message
laneh
Newbie
Newbie


Joined: 07 Apr 2011
Posts: 3

PostPosted: Thu Apr 07, 2011 7:15 pm    Post subject: Awesomeness Reply with quote

Thank you so much boss,

That worked like a champ.
_________________
If we spend so much time reinventing the wheel, how much time will we have left to drive the car?
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