WORKING_HOURS

Calculate working hours between two datetimes

Formula definition
=ROUND(IF(start_datetime>end_datetime,-1,
  IF(
    working_hours_start<=working_hours_end,
    MAX(ARRAYFORMULA(SUM(IF(
      (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_end/24)>start_datetime)*
      (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)<end_datetime),
      (IF(
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_end/24))<
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0),
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_end/24)),
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0)
      ))-
      (IF(
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24))>
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0),
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)),
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0)
      )),
      0)
    ) * 24), -1),
    MAX(ARRAYFORMULA(SUM(IF(
      (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)<=end_datetime)*
      (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+1+(working_hours_end/24)>=start_datetime),
      (IF(
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+1+(working_hours_end/24))<
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0),
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+1+(working_hours_end/24)),
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0)
      ))-
      (IF(
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24))>
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0),
        (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)),
        SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0)
      )),
      0)
    ) * 24), -1)
  )
), 2)

Function Details

This function calculates the number of working hours between two datetimes, taking into account the start and end times of the working day. It is useful for determining the duration of work shifts, project timelines, or other time-sensitive tasks that require tracking working hours. To use this function, input the start datetime (start_datetime), end datetime (end_datetime), start (e.g., 9 for 9:00 AM) and end (e.g., 17 for 5:00 PM) working hours as numbers. For example: WORKING_HOURS(A1, B1, 9, 17). If there is no valid difference (for example, the end date is before the start date), it defaults to -1. If your working hours are overnight (e.g., 10:00 PM to 6:00 AM), this is also supported by the function, for example: WORKING_HOURS(A1, B1, 22, 6).

Function name: WORKING_HOURS

Function description: Calculate working hours between two datetimes

Argument placeholders: start_datetime, end_datetime, working_hours_start, working_hours_end

Formula definition: =ROUND(IF(start_datetime>end_datetime,-1, IF( working_hours_start<=working_hours_end, MAX(ARRAYFORMULA(SUM(IF( (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_end/24)>start_datetime)* (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)<end_datetime), (IF( (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_end/24))< SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0), (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_end/24)), SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0) ))- (IF( (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24))> SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0), (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)), SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0) )), 0) ) * 24), -1), MAX(ARRAYFORMULA(SUM(IF( (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)<=end_datetime)* (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+1+(working_hours_end/24)>=start_datetime), (IF( (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+1+(working_hours_end/24))< SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0), (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+1+(working_hours_end/24)), SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,end_datetime,0) ))- (IF( (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24))> SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0), (SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,DATEVALUE(start_datetime))+(working_hours_start/24)), SEQUENCE(DATEVALUE(end_datetime)-DATEVALUE(start_datetime)+1,1,start_datetime,0) )), 0) ) * 24), -1) ) ), 2)

Argument description (start_datetime): The start datetime.

Argument example (start_datetime): A1

Argument description (end_datetime): The end datetime.

Argument example (end_datetime): B1

Argument description (working_hours_start): The start of working hours in 24-hour whole number format.

Argument example (working_hours_start): 9

Argument description (working_hours_end): The end of working hours in 24-hour whole number format.

Argument example (working_hours_end): 17

What is a Named Function in Google Sheets?

Named functions enable the creation of custom, reusable formulas that mimic built-in functions, streamlining calculations and data manipulations. These functions simplify complex formulas, making spreadsheets more readable and less prone to errors. By encapsulating intricate logic within a single function call, they enhance consistency across your data. Utilizing named functions reduces the need to write lengthy formulas repeatedly, thereby improving workflow efficiency and productivity in data analysis and management.

How to Add This Function to Google Sheets (Easy Download & Import)

Follow these simple steps to download and import the function into your spreadsheet. This method is the quickest and easiest way to add the named function to your Google Sheets document, but will not include the argument description and examples:

  1. Download the Formula: Click on the download button at the top of this page to download a file with the formula.
  2. Open Google Sheets: Open your Google Sheets document, from the top menu select Data > Named functions. Click Import function.
  3. Import the function: Select Upload and select the file you downloaded with the function. Click Import all or select which function(s) to import and click Import.

Once added, the function will be ready to use in your document like any other built-in function. Simply type the function name and provide the required inputs to use it in your calculations.

How to Add This Function to Google Sheets (Manual)

Follow these simple steps to integrate the function into your spreadsheet:

  1. Open Google Sheets: Open your Google Sheets document, from the top menu select Data > Named functions. Click Add new function.
  2. Copy the Formula: For each input copy and paste the information from above.
    • Copy the name of the function to the Function name input.
    • Copy the description of the function to the Function description input.
    • Copy each placeholder one at a time into the Argument placeholders input, if there are any placeholdes.
    • Copy the formula of the function to the Formula definition input.
    Click Next.
  3. Add additional details: Optionally you can add a description and example for the placeholders.
  4. Save the function: Click Create to add the function to your document.

Once added, the function will be ready to use in your document like any other built-in function. Simply type the function name and provide the required inputs to use it in your calculations.

Copyright © 2024 Keshia Rose. All rights reserved for website content. Individual functions are available under an MIT License.

This site is not associated with or endorsed by Google.