Need help with this extensive formula

grev

New Member
Joined
Sep 4, 2002
Messages
21
The result for this is either a zero or a numerical value > 1. I am trying to replace the zero with a blank. However when I do calculations it gives me an error. How can I use this and turn the blank into a calculable result. Thanks for the help.

=IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13),HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),"0")+IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13),HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),"0")
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
On 2002-09-20 12:58, grev wrote:
The result for this is either a zero or a numerical value > 1. I am trying to replace the zero with a blank. However when I do calculations it gives me an error. How can I use this and turn the blank into a calculable result. Thanks for the help.

=IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13),HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),"0")+IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13),HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),"0")

May I suggest that you install the add-in morefunc.xll, downloadable from:

http://longre.free.fr/english/index.html

and use the following formula instead:


=IF(ISNA(SETV(HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0))),0,GETV())+IF(ISNA(SETV(HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0))),0,GETV())

You have "0" in the original formula: that should be just 0 without double quotes.
 
Upvote 0
On 2002-09-20 12:58, grev wrote:
The result for this is either a zero or a numerical value > 1. I am trying to replace the zero with a blank. However when I do calculations it gives me an error. How can I use this and turn the blank into a calculable result. Thanks for the help.

=IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13),HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),"0")+IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13),HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),"0")


This edits YOUR formula to leave a blank

=IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),"")&IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),"")
This message was edited by dave patton on 2002-09-20 13:26
 
Upvote 0
Im sorry i forgot to mention I currently have left the zero's because they calculate. If I replace the zeros with blanks that is when the problem occurs.

I am using this formula to lookup values from other tables and retreive their respective values.
 
Upvote 0
On 2002-09-20 13:27, grev wrote:
Im sorry i forgot to mention I currently have left the zero's because they calculate. If I replace the zeros with blanks that is when the problem occurs.

I am using this formula to lookup values from other tables and retreive their respective values.

If you need to replace 0's (without double quotes around), although I don't see why, you can use SUM instead of +...

=SUM(IF(...),IF(...))

Try using morefunc though.
 
Upvote 0
You stated at the beginning that you wanted to replace the 0 with a blank.

Wrap the formula with an If. The following uses MoreFunc.

Either Aladin's
=IF(SETV(IF(ISNA(SETV(HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),0)),0,GETV())+IF(ISNA(SETV(HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),1)),0,GETV(1)),2),GETV(2),"")

or
=IF(SETV(IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),0)+IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),0),2),GETV(2),"")
 
Upvote 0
[...]
=IF(SETV(IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),0)+IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),0),2),GETV(2),"")

Dave,

Keeping COUNTIF in defeats the purpose of SETV/GETV.

Aladin
 
Upvote 0
On 2002-09-20 14:10, Aladin Akyurek wrote:
[...]
=IF(SETV(IF(COUNTIF('TRKLD SCHED'!$V$1:$BC$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$V$1:$BC$113,107,0),0)+IF(COUNTIF('TRKLD SCHED'!$D$1:$N$1,A13)>0,HLOOKUP(A13,'TRKLD SCHED'!$D$1:$N$113,107,0),0),2),GETV(2),"")

Dave,

Keeping COUNTIF in defeats the purpose of SETV/GETV.

Aladin

I know. I was just trying to complete OP's original question of showing number >0 or blank.

I showed the diferent solutions but instead of wrapping everything with IF and repeating the formula, I used the more efficient Setv and Getv combo.
 
Upvote 0

Forum statistics

Threads
1,213,565
Messages
6,114,338
Members
448,570
Latest member
rik81h

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top