ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Need help on counting text within certain criteria (https://www.excelbanter.com/excel-worksheet-functions/85564-need-help-counting-text-within-certain-criteria.html)

christinac

Need help on counting text within certain criteria
 
I have a spreadsheet that I am setting up to show holidays and sickness days.
The table looks like this:


Name Week 1 Week 2
M T W T F M T W T F

EMPLOYEE F F H F F

F = Full day holiday
H = Half day holiday

This bit is easy because I used Countif to calculate the number of days.
However, I need to convert it to hours which is a little more complicated.
The hours worked are Monday - Thursday 8.5 Hours, Friday - 5 hours. Only
five fridays per year can be taken as holiday.

I need a formula that will count the number of F entries and multiply it by
8.5 except if it is a Friday which be multiplied by 5. How do I do this?
--
Chris

Stefi

Need help on counting text within certain criteria
 
Enter this formula in G4:
=8.5*SUMPRODUCT(--(B4:F4="F"),--(B2:F2<"F"))
+5*SUMPRODUCT(--(B4:F4="F"),--(B2:F2="F"))
A B C D E F G
1 Name Week 1
2 M T W T F
3
4 EMPLOYEE F F H F formula

Regards,
Stefi


Bob Phillips

Need help on counting text within certain criteria
 
Assuming the day code is in B2:IV2, and the F/H codes are in B3:M3 (then 4,
etc) the total for row 3 is]

=SUM(IF($B3:$IV3<"",IF($B3:$IV3="F",IF($B$2:$IV$2 ="F",4,8),IF($B$2:$IV$2="F
",2.5,5))))

which is an array formula, it should be committed with Ctrl-Shift-Enter, not
just Enter.

--
HTH

Bob Phillips

(remove nothere from email address if mailing direct)

"christinac" wrote in message
...
I have a spreadsheet that I am setting up to show holidays and sickness

days.
The table looks like this:


Name Week 1 Week 2
M T W T F M T W T F

EMPLOYEE F F H F F

F = Full day holiday
H = Half day holiday

This bit is easy because I used Countif to calculate the number of days.
However, I need to convert it to hours which is a little more complicated.
The hours worked are Monday - Thursday 8.5 Hours, Friday - 5 hours. Only
five fridays per year can be taken as holiday.

I need a formula that will count the number of F entries and multiply it

by
8.5 except if it is a Friday which be multiplied by 5. How do I do this?
--
Chris




christinac

Need help on counting text within certain criteria
 
Thank you! That worked perfectly!
--
Chris


"Stefi" wrote:

Enter this formula in G4:
=8.5*SUMPRODUCT(--(B4:F4="F"),--(B2:F2<"F"))
+5*SUMPRODUCT(--(B4:F4="F"),--(B2:F2="F"))
A B C D E F G
1 Name Week 1
2 M T W T F
3
4 EMPLOYEE F F H F formula

Regards,
Stefi


Ardus Petus

Need help on counting text within certain criteria
 
Assuming your day headers (MTWTF) are in row #2, starting with col C
and your hours total in col B
B1: =SUMPRODUCT((C3:AZ3="F")*(((C$2:AZ$2="F")*5)+(C$2: AZ$2<"F")*8.5))

HTH
--
AP


"christinac" a écrit dans le message
de ...
I have a spreadsheet that I am setting up to show holidays and sickness

days.
The table looks like this:


Name Week 1 Week 2
M T W T F M T W T F

EMPLOYEE F F H F F

F = Full day holiday
H = Half day holiday

This bit is easy because I used Countif to calculate the number of days.
However, I need to convert it to hours which is a little more complicated.
The hours worked are Monday - Thursday 8.5 Hours, Friday - 5 hours. Only
five fridays per year can be taken as holiday.

I need a formula that will count the number of F entries and multiply it

by
8.5 except if it is a Friday which be multiplied by 5. How do I do this?
--
Chris




Stefi

Need help on counting text within certain criteria
 
You are welcome, thanks for the feedback!
Stefi


€˛christinac€¯ ezt Ć*rta:

Thank you! That worked perfectly!
--
Chris


"Stefi" wrote:

Enter this formula in G4:
=8.5*SUMPRODUCT(--(B4:F4="F"),--(B2:F2<"F"))
+5*SUMPRODUCT(--(B4:F4="F"),--(B2:F2="F"))
A B C D E F G
1 Name Week 1
2 M T W T F
3
4 EMPLOYEE F F H F formula

Regards,
Stefi



All times are GMT +1. The time now is 10:47 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com