Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi, Following previous advice, the following formula returns the % "Yes" in a
range from J84:J**; ** being referenced from a value in cell A2. Is it possible to now tweek this formula so that the first part of the range (J84)is also remotely referenced from a value in say B2 ? i.e. J"&B2:J"&A2 ? =COUNTIF(INDIRECT("J84:J"&A2),"Yes")/COUNTA(INDIRECT("J84:J"&A2))*100 Many Thanks |
#2
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Try this:
=COUNTIF(INDIRECT("J"&B2&":J"&A2),"Yes")/COUNTA(INDIRECT("J"&B2&":J"&A2))*100 HTH, Elkar "Graham" wrote: Hi, Following previous advice, the following formula returns the % "Yes" in a range from J84:J**; ** being referenced from a value in cell A2. Is it possible to now tweek this formula so that the first part of the range (J84)is also remotely referenced from a value in say B2 ? i.e. J"&B2:J"&A2 ? =COUNTIF(INDIRECT("J84:J"&A2),"Yes")/COUNTA(INDIRECT("J84:J"&A2))*100 Many Thanks |
#3
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
=COUNTIF(INDIRECT("J" & B2 &":J"&A2),"Yes")/COUNTA(INDIRECT("J" & B2
&":J"&A2))*100 "Graham" wrote: Hi, Following previous advice, the following formula returns the % "Yes" in a range from J84:J**; ** being referenced from a value in cell A2. Is it possible to now tweek this formula so that the first part of the range (J84)is also remotely referenced from a value in say B2 ? i.e. J"&B2:J"&A2 ? =COUNTIF(INDIRECT("J84:J"&A2),"Yes")/COUNTA(INDIRECT("J84:J"&A2))*100 Many Thanks |
#4
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Graham wrote...
Hi, Following previous advice, the following formula returns the % "Yes" in a range from J84:J**; ** being referenced from a value in cell A2. Is it possible to now tweek this formula so that the first part of the range (J84)is also remotely referenced from a value in say B2 ? i.e. J"&B2:J"&A2 ? =COUNTIF(INDIRECT("J84:J"&A2),"Yes")/COUNTA(INDIRECT("J84:J"&A2))*100 Yes, but there's a better way to do this. =COUNTIF(INDEX(J:J,B2):INDEX(J:J,A2),"Yes") /COUNTA(INDEX(J:J,B2):INDEX(J:J,A2))*100 Better still would be to restict this to the largest possible range. If that were J1:J1000, =COUNTIF(INDEX(J1:J1000,B2):INDEX(J1:J1000,A2),"Ye s") /COUNTA(INDEX(J1:J1000,B2):INDEX(J1:J1000,A2))*100 Then there's shorter. =100*PRODUCT(COUNTIF(INDEX(J1:J1000,B2):INDEX(J1:J 1000,A2), {"Yes","<"})^{1,-1}) |
#5
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Many thanks to you both!
"Elkar" wrote: Try this: =COUNTIF(INDIRECT("J"&B2&":J"&A2),"Yes")/COUNTA(INDIRECT("J"&B2&":J"&A2))*100 HTH, Elkar "Graham" wrote: Hi, Following previous advice, the following formula returns the % "Yes" in a range from J84:J**; ** being referenced from a value in cell A2. Is it possible to now tweek this formula so that the first part of the range (J84)is also remotely referenced from a value in say B2 ? i.e. J"&B2:J"&A2 ? =COUNTIF(INDIRECT("J84:J"&A2),"Yes")/COUNTA(INDIRECT("J84:J"&A2))*100 Many Thanks |
#6
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Thank-you to you too Harlan. When you say 'better way to do this', in what
context ? The previous works, would it be worth my while to change it to your suggestion ? There often appear to be different ways of achieving the same result in Excel ? "Harlan Grove" wrote: Graham wrote... Hi, Following previous advice, the following formula returns the % "Yes" in a range from J84:J**; ** being referenced from a value in cell A2. Is it possible to now tweek this formula so that the first part of the range (J84)is also remotely referenced from a value in say B2 ? i.e. J"&B2:J"&A2 ? =COUNTIF(INDIRECT("J84:J"&A2),"Yes")/COUNTA(INDIRECT("J84:J"&A2))*100 Yes, but there's a better way to do this. =COUNTIF(INDEX(J:J,B2):INDEX(J:J,A2),"Yes") /COUNTA(INDEX(J:J,B2):INDEX(J:J,A2))*100 Better still would be to restict this to the largest possible range. If that were J1:J1000, =COUNTIF(INDEX(J1:J1000,B2):INDEX(J1:J1000,A2),"Ye s") /COUNTA(INDEX(J1:J1000,B2):INDEX(J1:J1000,A2))*100 Then there's shorter. =100*PRODUCT(COUNTIF(INDEX(J1:J1000,B2):INDEX(J1:J 1000,A2), {"Yes","<"})^{1,-1}) |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Dynamic Ranges | Excel Discussion (Misc queries) | |||
Dynamic ranges | Charts and Charting in Excel | |||
Dynamic Ranges | Excel Discussion (Misc queries) | |||
dynamic ranges | Excel Worksheet Functions | |||
Dynamic Formulas with Dynamic Ranges | Excel Worksheet Functions |