setting cell value to 1 based on 2 conditions

d3ad3y3

New Member
Joined
Nov 4, 2024
Messages
6
Office Version
  1. 2013
Platform
  1. Windows
Hi everyone, i need help regarding the formula i try to use, i use 3 columns, Date, Activity and Validity. Validity should be set to 1 at the end of the last same date if and only if there is atleast 1 Service each date, see example below

dateactivityvalidity
1-OctDeliver
1-OctService
1-OctService1
2-OctPickup
2-OctDeliver
3-OctService1
4-OctService1

tried to use countif but if the first activity of the day is not Service, the validity wont be set to 1.
 
Thanks

@Peter_SSs

I might have missed something in the thread but wouldn't this simpler formula in col E do the same thing?
much better as i said in an earlier post
i think this is overcomplicated a formula - seems to work - but i have not fully tested
I thought i was overcomplicated the formula
Thanks for simplifying - HOPEFULLY the OP will try

*d3ad3y3

alright, as of now i dont experience any unusual using the last long formula with max(), ill try to replace the formula with this shorten one, i think can shorten it more by replacing the 2nd and 3rd "service" string with B2 instead. thanks for your help again.
I think

Peter_SSs

would be a better easier solution
 
Upvote 1

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
I might have missed something in the thread but wouldn't this simpler formula in col E do the same thing?

24 11 05.xlsm
ABCDE
1dateactivityvalidityformula reducedformula reduced
21-OctDeliver  
31-OctService  
41-OctService111
52-OctPickup  
62-OctDeliver  
73-OctService111
84-OctService111
94-OctDeliver  
Sheet2 (2)
Cell Formulas
RangeFormula
D2:D9D2=IF(AND(B2="service",COUNTIFS($A$2:A2,A2,$B$2:B2,"service") =COUNTIFS($A$2:$A$100,A2,$B$2:$B$100,"service") ),1,"")
E2:E9E2=IF(AND(B2="service",COUNTIFS(A2:A$100,A2,B2:B$100,B2)=1),1,"")


hi, thanks for your help too, this is the modified formula i used in my workbook, =IF(AND($B7="Service",COUNTIFS($A7:$A$260,$A7,$B7:$B$260,$B7)=1),1,0)
your formula is interesting since the A2 was not locked so it moves down with the current row, removing the need to use another COUNTIFS, just need to check for =1, thank you also
 
Upvote 0
this is the modified formula i used in my workbook, =IF(AND($B7="Service",COUNTIFS($A7:$A$260,$A7,$B7:$B$260,$B7)=1),1,0)
Originally you had 1 or blank as results in the formula column. Your latest formula now has 1 or 0. If that is what you want the formula can be simplified again slightly.
Excel Formula:
=--AND($B7="Service",COUNTIFS($A7:$A$260,$A7,$B7:$B$260,$B7)=1)

your formula is interesting since the A2 was not locked so it moves down with the current row
If the current row is "Service" there is no point looking upwards to see if this is the last one. ;)
 
Upvote 0
Solution
Originally you had 1 or blank as results in the formula column. Your latest formula now has 1 or 0. If that is what you want the formula can be simplified again slightly.
=--AND($B7="Service",COUNTIFS($A7:$A$260,$A7,$B7:$B$260,$B7)=1)
Oops, since I was simplifying & the formula appears to just be copied down the column, perhaps I should have taken back out the extra $ signs that you added after post 10 as well? :biggrin:
Excel Formula:
=--AND(B7="Service",COUNTIFS(A7:A$260,A7,B7:B$260,B7)=1)
 
Upvote 0

Forum statistics

Threads
1,223,577
Messages
6,173,164
Members
452,504
Latest member
frankkeith2233

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