SOLVED

Return latest date for billing

Copper Contributor

I need a formula to help me with the billing process. I want it to help with if billing is YES of NO.
Please see below excel example.

Billing is YES if any equipment went to for inspection or went for inspection after 5 workdays. Billing is NO if any equipment went for inspection within 5 workdays. (not counting Saturdays and Sundays) 
But if the equipment went for inspection on a Saturday the formula will need to count the Saturdays also. 

 

Someone already helped me with the following formulas:

- IF(NETWORKDAYS(MAXIFS(A$1:A1,G$1:G1,G2),A2)>5,"YES","NO"). Here it only counts the workdays.

- IF(NETWORKDAYS.INTL(MAXIFS(A$1:A1,G$1:G1,G2),A2,11)>5,"YES","NO"). Here it doesn't count the Sundays only.

 

But somehow i need to put these 2 together. Cause if the equipment went for inspection on a Saturday it does need to count the Saturday + the normal workdays. And if an equipment went on a normal workday (Mon-Fri)  it doesn't count the Saturday and Sunday. 

 

 

CLIENTINSPECTION DATEINSPECTION VALID TILLINSPECTION LOCATIONBUSINESS PARTNER NAMEEQUIPMENT MODELEQUIPMENT NUMBERLICENSE NUMBERSTATUSSTICKER NUMBERBILLABLE
Mike23-Jun-2120-Jul-21ParboFORDBUSPOO17485A6dBPASSED  YES
Brock16-Jul-22 ParboHCABUSPOO17485A6dBFAILED YES
Mike22-Jul-2215-Aug-21WanicaHCABUSPOO17485A6dBPASSED  NO
Mike14-Aug-2111-Sep-21WanicaBLUEBUSPOO17485A6dBPASSED  YES
Brock18-Nov-2110-Feb-22ParboBAYD-MAXPOO123301w9hpPASSED  YES
Brock18-Nov-2110-Feb-22WanicaHCAAMAROKPOO12343e71gzPASSED  YES
8 Replies

@RobertoKartoredjo 

That could be

=IF( NETWORKDAYS.INTL( E5, F5, 1 + 10*(WEEKDAY( E5, 1 ) = 7) ) > 5, "Yes", "No" )

It takes as days-off Sat and Sun for any days but if start on Sat, otherwise Sun only

@Sergei Baklan 

 

Thank you. But i do get the following below. On the 20 Aug the billing is supposed to be YES. 

INSPECTION DATEINSPECTION VALID TILLINSPECTION LOCATIONBUSINESS PARTNER NAMEEQUIPMENT MODELEQUIPMENT NUMBERLICENSE NUMBERSTATUSSTICKER NUMBERBILLABLE
5-Aug-22 CALYPSONAARTKO NVBUS - CAT 3 3498BBFAILED YES
12-Aug-22 CALYPSONAARTKO NVBUS - CAT 3 3498BBPASSED YES
15-Aug-22 CALYPSONAARTKO NVBUS - CAT 3 2222CDFAILED YES
20-Aug-22 CALYPSONAARTKO NVBUS - CAT 3 2222CDPASSED NO

@RobertoKartoredjo 

How about

=IF(NETWORKDAYS.INTL(MAXIFS(A$1:A1,G$1:G1,G2),A2,IF(WEEKDAY(A2)=7,11,1))>5,"YES","NO")

in row 2.

@Hans Vogelaar 

 

Hi Hans,

Thank you but, 

I tried it and i get Billing "NO" on the 12th of Aug but this needs to be "YES" actually cause it does need to count the Saturday on the 6th when the equipment went for inspection the first time. 

INSPECTION DATEINSPECTION VALID TILLINSPECTION LOCATIONBUSINESS PARTNER NAMEEQUIPMENT MODELEQUIPMENT NUMBERLICENSE NUMBERSTATUSSTICKER NUMBERBILLABLE
6-Aug-22 CALYPSONAARTKO NVTRUCK - CAT 4334444RDFAILED YES
12-Aug-224-Nov-22CALYPSONAARTKO NVTRUCK - CAT 4334444RDPASSED NO
best response confirmed by VI_Migration (Silver Contributor)
Solution

@RobertoKartoredjo 

Perhaps

 

=IF(NETWORKDAYS.INTL(MAXIFS(A$1:A1,G$1:G1,G2),A2,IF(OR(WEEKDAY(A2)=7,WEEKDAY(MAXIFS(A$1:A1,G$1:G1,G2))=7),11,1))>5,"YES","NO")

@Hans Vogelaar 

 

Hi Hans,

 

Thank you. This works! Thank you again for this.

Dankjewel 

@Hans Vogelaar@RobertoKartoredjo@Sergei Baklan@RobertoKartoredjo 

Im sorry to bother you guys again but they put in yet another variable in the Excel file. Making it more challenging.  

Looking at the first column. That indicates that the same VH is inspected for 2 different sites aka client. meaning they need to be billed for both. With the current formula it says that billing is "No" ( which is actually correct if there was just 1 site aka client).
Is it possible to add the "CLIENT" column also in the formula?

@RobertoKartoredjo 

Perhaps

=IF(NETWORKDAYS.INTL(MAXIFS(B$1:B1,A$1:A1,A1,H$1:H1,H2),B2,IF(OR(WEEKDAY(B2)=7,WEEKDAY(MAXIFS(B$1:B1,A$1:A1,A1,H$1:H1,H2))=7),11,1))>5,"YES","NO")

but your sample workbook has so few data that I cannot test it meaningfully.

1 best response

Accepted Solutions
best response confirmed by VI_Migration (Silver Contributor)
Solution

@RobertoKartoredjo 

Perhaps

 

=IF(NETWORKDAYS.INTL(MAXIFS(A$1:A1,G$1:G1,G2),A2,IF(OR(WEEKDAY(A2)=7,WEEKDAY(MAXIFS(A$1:A1,G$1:G1,G2))=7),11,1))>5,"YES","NO")

View solution in original post