+ Reply to Thread
Results 1 to 6 of 6

Need help on counting text within certain criteria

  1. #1
    christinac
    Guest

    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

  2. #2
    Stefi
    Guest

    RE: 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


  3. #3
    Bob Phillips
    Guest

    Re: 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" <[email protected]> wrote in message
    news:[email protected]...
    > 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




  4. #4
    christinac
    Guest

    RE: 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
    >


  5. #5
    Ardus Petus
    Guest

    Re: 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" <[email protected]> a écrit dans le message
    de news:[email protected]...
    > 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




  6. #6
    Stefi
    Guest

    RE: 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
    > >


+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1