Skip to content
Snippets Groups Projects
Unverified Commit b85be3e7 authored by Natalie's avatar Natalie Committed by GitHub
Browse files

docs - convertTimezone, datetimeAdd, datetimeSubtract, and datetimeDiff (#26685)

parent bca3d704
No related branches found
No related tags found
No related merge requests found
......@@ -32,7 +32,9 @@ For an introduction to expressions, check out [Writing expressions in the notebo
- [coalesce](./expressions/coalesce.md)
- [concat](./expressions/concat.md)
- [contains](#contains)
- [convertTimezone](./expressions/converttimezone.md)
- [datetimeAdd](./expressions/datetimeadd.md)
- [datetimeDiff](./expressions/datetimediff.md)
- [datetimeSubtract](./expressions/datetimesubtract.md)
- [day](#day)
- [endswith](#endswith)
......@@ -268,17 +270,31 @@ Example: `contains([Status], "Class")`. If `Status` were "Classified", the expre
Related: [regexextract](#regexextract).
### [convertTimezone](./expressions/converttimezone.md)
Shifts a date or timestamp value into a specified time zone.
Syntax: `convertTimezone(column, target, source)`.
Example: `convertTimezone("2022-12-28T12:00:00", "Canada/Pacific", "Canada/Eastern")` would return the value `2022-12-28T09:00:00`, displayed as `December 28, 2022, 9:00 AM`.
### [datetimeAdd](./expressions/datetimeadd.md)
Adds some unit of time to a date or timestamp value.
Syntax: `datetimeAdd(column, amount, unit)`.
- column: the column with your date or timestamp values.
- amount: The number of units to be added.
- units: "year", "quarter", "month", "day", "hour", "second", or "millisecond".
Example: `datetimeAdd("2021-03-25", 1, "month")` would return the value `2021-04-25`, displayed as `April 25, 2021`.
Related: [between](#between), [datetimeSubtract](#datetimesubtract).
### [datetimeDiff](./expressions/datetimediff.md)
Returns the difference between two datetimes in some unit of time. For example, `datetimeDiff(d1, d2, "day") ` will return the number of days between `d1` and `d2`.
Syntax: `datetimeDiff(datetime1, datetime2, unit)`.
Example: `datetimeAdd("March 25, 2021, 12:52:37", 1, "month")` would return `April 25, 2021, 12:52:37`.
Example: `datetimeDiff("2022-02-01", "2022-03-01", "month")` would return `1`.
### [datetimeSubtract](./expressions/datetimesubtract.md)
......@@ -286,17 +302,15 @@ Subtracts some unit of time from a date or timestamp value.
Syntax: `datetimeSubtract(column, amount, unit)`.
- column: the column with your date or timestamp values.
- amount: The number of units to be subtracted.
- units: "year", "quarter", "month", "day", "hour", "second", or "millisecond".
Example: `datetimeSubtract("2021-03-25", 1, "month")` would return the value `2021-02-25`, displayed as `February 25, 2021`.
Example: `datetimeSubtract("March 25, 2021, 12:52:37", 1, "month")` would return `February 25, 2021, 12:52:37`.
Related: [between](#between), [datetimeAdd](#datetimeadd).
### day
Takes a datetime and returns the day of the month as an integer.
Syntax: `day([datetime column)`.
Syntax: `day([datetime column])`.
Example: `day("March 25, 2021, 12:52:37")` would return the day as an integer, `25`.
......@@ -404,7 +418,7 @@ Related: [upper](#upper).
Takes a datetime and returns the minute as an integer (0-59).
Syntax: `minute(datetime column)`.
Syntax: `minute([datetime column])`.
Example: `minute("March 25, 2021, 12:52:37")` would return `52`.
......@@ -412,7 +426,7 @@ Example: `minute("March 25, 2021, 12:52:37")` would return `52`.
Takes a datetime and returns the month number (1-12) as an integer.
Syntax: `month(datetime)`.
Syntax: `month([datetime column])`.
Example: `month("March 25, 2021, 12:52:37")` would return the month as an integer, `3`.
......@@ -432,7 +446,7 @@ Related: [exp](#exp).
Takes a datetime and returns the number of the quarter in a year (1-4) as an integer.
Syntax: `quarter([datetime column)`.
Syntax: `quarter([datetime column])`.
Example: `quarter("March 25, 2021, 12:52:37")` would return `1` for the first quarter.
......
---
title: ConvertTimezone
---
# ConvertTimezone
`convertTimezone` shifts a timestamp into a specified time zone by adding or subtracting the right interval from the timestamp.
| Syntax | Example |
|-----------------------------------------------------------------------|-----------------------------------------------------------------------------------|
| `convertTimezone(column, target, source)` | `convertTimezone("2022-12-28T12:00:00", "Canada/Pacific", "Canada/Eastern")` |
| Shifts a timestamp from the source time zone to the target time zone. | Returns the value `2022-12-28T09:00:00`, displayed as `December 28, 2022 9:00 AM` |
Timestamps and time zones are rather nasty to work with (it's easy to make mistakes, and difficult to catch them), so you should only try to use `convertTimezone` if the interpretation of your data is sensitive to time-based cutoffs.
For example, if you're tracking user logins over time, you probably won't run your business differently if some logins get counted on Mondays instead of Tuesdays. However, if you're using Metabase to do something precise, like your taxes, you (and the government) will probably care a lot more about the difference between transactions that occurred on Dec 31 vs. Jan 1.
## Parameters
`column` can be any of:
- The name of a timestamp column,
- a custom expression that returns a [timestamp](#accepted-data-types), or
- a string in the format `"YYYY-MM-DD` or `"YYYY-MM-DDTHH:MM:SS"`.
`target`:
- The name of the time zone you want to assign to your column.
`source`:
- The name of your column's current time zone.
- Required for columns or expressions with the data type `timestamp without time zone`.
- Optional for columns or expressions with the data type `timestamp with time zone`.
- For more info, see [Accepted data types](#accepted-data-types).
We support [tz database](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) time zone names (such as "Canada/Eastern" instead of "EST").
## Creating custom report dates
Let's say that you have some time series data that's stored in one or more time zones (**Source Time**). You want to create custom reporting dates for a team that lives in EST.
| Source Time | Team Report Time (EST) |
|------------------------------------|------------------------------|
| December 28, 2022, 10:00:00 | December 28, 2022, 07:00:00 |
| December 28, 2022, 21:00:00 | December 28, 2022, 19:00:00 |
| December 27, 2022, 08:00:00 | December 27, 2022, 05:00:00 |
If **Source Time** is stored as a `timestamp with time zone` or a `timestamp with offset`, you only need to provide the `target` time zone:
```
convertTimezone([Source Time], 'EST')
```
If **Source Time** is stored as a `timestamp without time zone`, you _must_ provide the `source` time zone (which will depend on your database time zone):
```
convertTimezone([Source Time], 'EST', 'UTC')
```
It's usually a good idea to label `convertTimezone` columns with the name of the target time zone (or add the target time zone to the metadata of a model). We promise this will make your life easier when someone inevitably asks why the numbers don't match.
If you're not getting the results that you expect:
- Check if you have the right [source time zone](#choosing-a-source-time-zone).
- Ask your database admin about `timestamp with time zone` vs. `timestamp without time zone` (for more info, see [Accepted data types](#accepted-data-types)).
### Choosing a source time zone
When you're doing time zone conversions, make sure you know the source time zone that you're working with. Different columns (and even different rows) in the same table, question, or model can be in different "source" time zones.
| Possible source time zone | Description | Example |
|-------------------------------|----------------------------------------------------------------------|------------------------------------------------------------------------------------------------------------------|
| Client time zone | Time zone where an event happened. | A web analytics service might capture data in the local time zone of each person who visited your website. |
| Database time zone | Time zone metadata that's been added to timestamps in your database. | It's a common database practice to store all timestamps in UTC. |
| No time zone | Missing time zone metadata | Databases don't _require_ you to store timestamps with time zone metadata. |
| Metabase report time zone | Time zone that Metabase uses to _display_ timestamps. | Metabase can display dates and times in PST, even if the dates and times are stored as UTC in your database. |
For example, say you have a table with one row for each person who visited your website. It's hard to tell, just from looking at `December 28, 2022, 12:00 PM`, whether the "raw" timestamp is:
- stored using your database's time zone (usually UTC),
- stored without time zone metadata (for example, if the website visitor is in HKT, then the timestamp `December 28, 2022, 12:00 PM` might "implicitly" use Hong Kong time),
- _displayed_ in your Metabase report time zone.
For more gory details, see [Limitations](#limitations).
## Accepted data types
| [Data type](https://www.metabase.com/learn/databases/data-types-overview#examples-of-data-types) | Works with `convertTimezone` |
| ----------------------- | -------------------- |
| String | ❌ |
| Number | ❌ |
| Timestamp | ✅ |
| Boolean | ❌ |
| JSON | ❌ |
We use "timestamp" and "datetime" to talk about any temporal data type that's supported by Metabase.
If your timestamps are stored as strings or numbers in your database, an admin can [cast them to timestamps](../../../data-modeling/metadata-editing.md#casting-to-a-specific-data-type) from the Data Model page.
To use `convertTimezone` without running into errors or pesky undetectable mistakes, you should know that there are a few varieties of `timestamp` data types:
| Data type | Description | Example |
|-------------------------------|-------------------------------------------|------------------------------------------------------|
| `timestamp with time zone` | Knows about location. | `2022-12-28T12:00:00 AT TIME ZONE 'America/Toronto'` |
| `timestamp with offset` | Knows about the time difference from UTC. | `2022-12-28T12:00:00-04:00` |
| `timestamp without time zone` | No time zone info. | `2022-12-28T12:00:00` |
Note that the first part of the timestamp is in UTC (same thing as GMT). The time zone or offset tells you how much time to add or subtract for a given time zone.
`convertTimezone` will work with all three types of timestamps, but the output of `convertTimezone` will always be a `timestamp without time zone`.
## Limitations
Metabase displays timestamps without time zone or offset information, which is why you have to be so careful about the [source time zone](#choosing-a-source-time-zone) when using `convertTimezone`.
The Metabase report time zone only applies to `timestamp with time zone` or `timestamp with offset` data types. For example:
| Raw timestamp | Report time zone | Displayed As |
|------------------------------------------|-------------------|------------------------|
| `2022-12-28T12:00:00 AT TIME ZONE 'CST'` | 'Canada/Eastern' | Dec 28, 2022, 7:00 AM |
| `2022-12-28T12:00:00-06:00` | 'Canada/Eastern' | Dec 28, 2022, 7:00 AM |
| `2022-12-28T12:00:00` | 'Canada/Eastern' | Dec 28, 2022, 12:00 AM |
The Metabase report time zone will not apply to the output of a `convertTimezone` expression. For example:
```
convertTimezone("2022-12-28T12:00:00 AT TIME ZONE 'Canada/Central'", "Canada/Pacific", "Canada/Central")
```
will produce a raw `timestamp without time zone`
```
2022-12-28T04:00:00
```
and displayed in Metabase as
```
Dec 28, 2022, 4:00 AM
```
If you use `convertTimezone` on a `timestamp without time zone`, make sure to use 'UTC' as the `source` time zone, otherwise the expression will shift your timestamp by the wrong amount. For example, if our `timestamp without time zone` is only "implied" to be in CST, we should use 'UTC' as the `source` parameter to get the same result as above.
For example, if we choose 'CST' as the `source` time zone for a `timestamp without time zone`:
```
convertTimezone("2022-12-28T12:00:00", "Canada/Pacific", "Canada/Central")
```
we'll get the raw `timestamp without time zone`
```
2022-12-28T10:00:00
```
displayed in Metabase as
```
Dec 28, 2022, 10:00 AM
```
## Related functions
This section covers functions and formulas that work the same way as the Metabase `convertTimezone` expression, with notes on how to choose the best option for your use case.
- [SQL](#sql)
- [Spreadsheets](#spreadsheets)
- [Python](#python)
### SQL
When you run a question using the [query builder](https://www.metabase.com/glossary/query_builder), Metabase will convert your graphical query settings (filters, summaries, etc.) into a query, and run that query against your database to get your results.
If our [timestamp sample data](#creating-custom-report-dates) is a `timestamp without time zone` stored in a PostgreSQL database, the source time zone will always be the Postgres database time zone, so we can convert it directly using:
```sql
SELECT source_time::TIMESTAMP AT TIME ZONE 'EST' AS team_report_time_est
```
which is the same as the `convertTimezone` expression _with_ a `source` parameter:
```
convertTimezone([Source Time], "Canada/Eastern", "UTC")
```
If `source_time` is a `timestamp with time zone` or `timestamp with offset` (for example, in a Snowflake database), then we don't need to specify a source time zone in SQL or in Metabase.
```sql
SELECT convert_timezone('America/Toronto', source_time) AS team_report_time_est
```
is the same as
```
convertTimezone([Source Time], "Canada/Eastern")
```
Remember that the time zone names depend on your database. For example, Snowflake doesn't accept most time zone abbreviations (like EST).
### Spreadsheets
If our [timestamp sample data](#creating-custom-report-dates) is in a spreadsheet where "Source Time" is in column A, we can change it to EST by subtracting the hours explicitly:
```
A1 - TIME(5, 0, 0)
```
to get the same result as
```
convertTimezone([Client Time], "Canada/Eastern")
```
### Python
If the [timestamp sample data](#creating-custom-report-dates) is stored in a `pandas` dataframe, you could convert the **Source Time** column to a `timestamp` object with time zone first(basically making a `timestamp without time zone` into a `timestamp with time zone`), then use `tz_convert` to change the time zone to EST:
```
df['Source Time (UTC)'] = pd.to_timestamp(df['Source Time'], utc=True)
df['Team Report Time (EST)'] = df['Source Time (UTC)'].dt.tz_convert(tz='Canada/Eastern')
```
to do the same thing as a nested `convertTimezone` expression
```
convertTimezone(convertTimezone([Source Time], "UTC"), "Canada/Eastern", "UTC")
```
## Further reading
- [Custom expressions documentation](../expressions.md)
- [Custom expressions tutorial](https://www.metabase.com/learn/questions/custom-expressions)
- [Time series comparisons](https://www.metabase.com/learn/questions/time-series-comparisons)
- [How to compare one time period to another](https://www.metabase.com/learn/dashboards/compare-times)
- [Working with dates in SQL](https://www.metabase.com/learn/sql-questions/dates-in-sql)
......@@ -6,25 +6,40 @@ title: DatetimeAdd
`datetimeAdd` takes a datetime value and adds some unit of time to it. This function is useful when you're working with time series data that's marked by a "start" and an "end", such as sessions or subscriptions data.
| Syntax | Example |
|-------------------------------------------------------------------------------------|------------------------------------------------------|
| `datetimeAdd(column, amount, unit)` | `datetimeAdd("March 25, 2021, 12:52:37", 1, "month")`|
| Takes a timestamp or date value and adds the specified number of time units to it. | `April 25, 2021, 12:52:37` |
| Syntax | Example |
|-------------------------------------------------------------------------------------|----------------------------------------|
| `datetimeAdd(column, amount, unit)` | `datetimeAdd("2021-03-25", 1, "month")`|
| Takes a timestamp or date value and adds the specified number of time units to it. | `2021-04-25` |
## Parameters
- Units can be any of: "year", "quarter", "month", "day", "hour", "second", or "millisecond".
- Amounts can be negative: `datetimeAdd("March 25, 2021, 12:52:37", -1, "month")` will return `February 25, 2021, 12:52:37`.
`column` can be any of:
- The name of a timestamp column,
- a custom expression that returns a [datetime](#accepted-data-types), or
- a string in the format `"YYYY-MM-DD"` or `"YYYY-MM-DDTHH:MM:SS"`(as shown in the example above).
`unit` can be any of:
- "year"
- "quarter"
- "month"
- "day"
- "hour"
- "second"
- "millisecond"
`amount`:
- A whole number or a decimal number.
- May be a negative number: `datetimeAdd("2021-03-25", -1, "month")` will return `2021-04-25`.
## Calculating an end date
Let's say you're a coffee connoisseur, and you want to keep track of the freshness of your beans:
| Coffee | Opened On | Finish By |
|------------------------|------------|------------|
| DAK Honey Dude | 2022-10-31 | 2022-11-14 |
| NO6 Full City Espresso | 2022-11-07 | 2022-11-21 |
| Ghost Roaster Giakanja | 2022-11-27 | 2022-12-11 |
| Coffee | Opened On | Finish By |
|------------------------|-------------------|-------------------|
| DAK Honey Dude | October 31, 2022 | November 14, 2022 |
| NO6 Full City Espresso | November 7, 2022 | November 21, 2022 |
| Ghost Roaster Giakanja | November 27, 2022 | December 11, 2022 |
Here, **Finish By** is a custom column with the expression:
......@@ -32,7 +47,24 @@ Here, **Finish By** is a custom column with the expression:
datetimeAdd([Opened On], 14, 'day')
```
You can use the [`between`](../expressions-list.md#between) or [`interval`](../expressions-list.md#interval) expressions to check if a given date falls between your start and end datetimes.
## Comparing a date to a window of time
To check if a specific datetime falls between your start and end datetimes, use [`between`](../expressions-list.md#between).
Unfortunately, Metabase doesn't currently support functions like `today`. If you want to check if today's date falls between **Opened On** and **Finish By** in the [Coffee example](#calculating-an-end-date):
1. Ask your database admin if there's table in your database that stores dates for reporting (sometimes called a date dimension table).
2. Create a new question using the date dimension table, with a filter for "Today".
3. Turn the "Today" question into a [model](../../../data-modeling/models.md).
4. Create a [left join](../../query-builder/join.md) between **Coffee** and the "Today" model on `[Opened On] <= [Today]` and `[Finish By] >= [Today]`.
The result should give you a **Today** column that's non-empty if today's date falls inside the coffee freshness window:
| Coffee | Opened On | Finish By | Today |
|------------------------|-------------------|-------------------|-------------------|
| DAK Honey Dude | October 31, 2022 | November 14, 2022 | November 11, 2022 |
| NO6 Full City Espresso | November 7, 2022 | November 21, 2022 | November 11, 2022 |
| Ghost Roaster Giakanja | November 27, 2022 | December 11, 2022 | |
## Accepted data types
......@@ -44,26 +76,13 @@ You can use the [`between`](../expressions-list.md#between) or [`interval`](../e
| Boolean | ❌ |
| JSON | ❌ |
This table uses `timestamp` and `datetime` interchangeably---just make sure that your dates and times aren't stored as string or a number data types in your database.
## Limitations
You can use `datetimeAdd` to _calculate_ relative dates given a column of date values, but unfortunately Metabase doesn't currently let you _generate_ a relative date (such as today's date).
For example, if you want to check if today's date falls between **Opened On** and **Finish By** in the [Coffee example](#calculating-an-end-date):
We use "timestamp" and "datetime" to talk about any temporal data type that's supported by Metabase.
- Ask your database admin if there's table in your database that stores dates for reporting (sometimes called a date dimension table).
- Create a new question using the date dimension table, with a filter for "Today".
- Turn the "Today" question into a model.
- Create a left join between **Coffee** and the "Today" model on `[Opened On] <= [Today]` and `[Finish By] >= [Today]`.
If your timestamps are stored as strings or numbers in your database, an admin can [cast them to timestamps](../../../data-modeling/metadata-editing.md#casting-to-a-specific-data-type) from the Data Model page.
The result should give you a **Today** column that's non-empty if today's date falls inside the coffee freshness window:
## Limitations
| Coffee | Opened On | Finish By | Today |
|------------------------|------------|------------|------------|
| DAK Honey Dude | 2022-10-31 | 2022-11-14 | 2022-11-10 |
| NO6 Full City Espresso | 2022-11-07 | 2022-11-21 | 2022-11-10 |
| Ghost Roaster Giakanja | 2022-11-27 | 2022-12-11 | |
If you're using MongoDB, `datetimeAdd` will only work on versions 5 and up.
## Related functions
......@@ -90,12 +109,12 @@ datetimeSubtract([Opened On], -14, "day")
does the same thing as
```
datetimeAdd([Opened On], 14, 'day')
datetimeAdd([Opened On], 14, "day")
```
### SQL
When you run a question using the [query_builder](https://www.metabase.com/glossary/query_builder), Metabase will convert your graphical query settings (filters, summaries, etc.) into a query, and run that query against your database to get your results.
When you run a question using the [query builder](https://www.metabase.com/glossary/query_builder), Metabase will convert your graphical query settings (filters, summaries, etc.) into a query, and run that query against your database to get your results.
If our [coffee sample data](#calculating-an-end-date) is stored in a PostgreSQL database:
......@@ -107,7 +126,7 @@ FROM coffee
is equivalent to the Metabase `datetimeAdd` expression:
```
datetimeAdd([Opened On], 14, 'day')
datetimeAdd([Opened On], 14, "day")
```
### Spreadsheets
......@@ -121,7 +140,7 @@ A:A + 14
produces the same result as
```
datetimeAdd([Opened On], 14, 'day')
datetimeAdd([Opened On], 14, "day")
```
Most spreadsheet tools require use different functions for different time units (for example, you'd use a different function to add "months" to a date). `datetimeAdd` makes it easy for you to convert all of those functions to a single consistent syntax.
......@@ -137,7 +156,7 @@ df['Finish By'] = df['Opened On'] + datetime.timedelta(days=14)
is equivalent to
```
datetimeAdd([Opened On], 14, 'day')
datetimeAdd([Opened On], 14, "day")
```
## Further reading
......
---
title: DatetimeDiff
---
# DatetimeDiff
`datetimeDiff` gets the amount of time between two datetime values, using the specified unit of time. Note that the difference is calculated in _whole_ units (see the example below).
| Syntax | Example |
|-----------------------------------------------------------------------------------------------------------|---------------------------------------------------------------|
| `datetimeDiff(datetime1, datetime2, unit)` | `datetimeDiff("2022-02-01", "2022-03-01", "month")` |
| Gets the difference between two datetimes (datetime2 minus datetime 1) using the specified unit of time. | `1` |
## Parameters
`datetime1` and `datetime2` can be:
- The name of a timestamp column,
- a custom expression that returns a [datetime](#accepted-data-types), or
- a string in the format `"YYYY-MM-DD"` or `"YYYY-MM-DDTHH:MM:SS"` (as shown in the example above).
`unit` can be any of:
- "year"
- "quarter"
- "month"
- "day"
- "hour"
- "second"
- "millisecond"
## Calculating age
Let's say you're a cheesemaker, and you want to keep track of your ripening process:
| Cheese | Aging Start | Aging End | Mature Age (Months) |
|-------------------|------------------|------------------|-----------------------|
| Provolone | January 19, 2022 | March 17, 2022 | 1 |
| Feta | January 25, 2022 | May 3, 2022 | 3 |
| Monterey Jack | January 27, 2022 | October 11, 2022 | 8 |
**Mature Age (Months)** is a custom column with the expression:
```
datetimeDiff([Aging Start], [Aging End], "month")
```
## Calculating current age
Metabase doesn't currently support datetime functions like `today`. To calculate the _current_ age of a cheese:
1. Ask your database admin if there's table in your database that stores dates for reporting (sometimes called a date dimension table).
2. Create a new question using the date dimension table, with a filter for "Today".
3. Turn the "Today" question into a [model](../../../data-modeling/models.md).
4. Create a [left join](../../query-builder/join.md) between **Cheese** and the "Today" model on `[Aging Start] <= [Today]`.
The result should give you a **Today** column that's non-empty if today's date is on or after the **Aging Start** date.
| Cheese | Aging Start | Aging End | Mature Age (Months) | Today | Current Age (Months) |
|-------------------|------------------|------------------|-----------------------|--------------------|-----------------------|
| Provolone | January 19, 2022 | March 17, 2022 | 1 | September 19, 2022 | 8 |
| Feta | January 25, 2022 | May 3, 2022 | 3 | September 19, 2022 | 7 |
| Monterey Jack | January 27, 2022 | October 11, 2022 | 8 | September 19, 2022 | 7 |
Then, you can calculate **Current Age (Months)** like this:
```
datetimeDiff([Aging Start], [Today], "month")
```
## Accepted data types
| [Data type](https://www.metabase.com/learn/databases/data-types-overview#examples-of-data-types) | Works with `datetimeDiff` |
| ----------------------- | -------------------- |
| String | ❌ |
| Number | ❌ |
| Timestamp | ✅ |
| Boolean | ❌ |
| JSON | ❌ |
We use "timestamp" and "datetime" to talk about any temporal data type that's supported by Metabase.
If your timestamps are stored as strings or numbers in your database, an admin can [cast them to timestamps](../../../data-modeling/metadata-editing.md#casting-to-a-specific-data-type) from the Data Model page.
## Related functions
This section covers functions and formulas that work the same way as the Metabase `datetimeDiff` expression, with notes on how to choose the best option for your use case.
- [SQL](#sql)
- [Spreadsheets](#spreadsheets)
- [Python](#python)
### SQL
When you run a question using the [query builder](https://www.metabase.com/glossary/query_builder), Metabase will convert your graphical query settings (filters, summaries, etc.) into a query, and run that query against your database to get your results.
If our [cheese sample data](#calculating-age) is stored in a PostgreSQL database:
```sql
SELECT DATE_PART('month', AGE(aging_end, aging_start)) AS mature_age_months
FROM cheese
```
is equivalent to the Metabase `datetimeDiff` expression:
```
datetimeDiff([Aging Start], [Aging End], "month")
```
Some databases, such as Snowflake and BigQuery, support functions like `DATEDIFF` or `DATE_DIFF`. For more info, check out our list of [common SQL reference guides](https://www.metabase.com/learn/debugging-sql/sql-syntax#common-sql-reference-guides).
### Spreadsheets
If our [cheese sample data](#calculating-age) is in a spreadsheet where "Aging Start" is in column B and "Aging End" is in column C:
```
DATEDIF(B1, C1, "M")
```
produces the same result as
```
datetimeDiff([Aging Start], [Aging End], "month")
```
Yes, `DATEDIF` looks a bit wrong, but the spreadsheet function really is `DATEDIF()` with one "f", not `DATEDIFF()`.
### Python
Assuming the [cheese sample data](#calculating-age) is in a `pandas` dataframe column called `df`, you can subtract the dates directly and use `numpy`'s `timedelta64` to convert the difference to months:
```
df['Mature Age (Months)'] = (df['Aging End'] - df['Aging Start']) / np.timedelta64(1, 'M')
```
is equivalent to
```
datetimeDiff([Aging Start], [Aging End], "month")
```
## Further reading
- [Custom expressions documentation](../expressions.md)
- [Custom expressions tutorial](https://www.metabase.com/learn/questions/custom-expressions)
- [Time series comparisons](https://www.metabase.com/learn/questions/time-series-comparisons)
- [How to compare one time period to another](https://www.metabase.com/learn/dashboards/compare-times)
- [Working with dates in SQL](https://www.metabase.com/learn/sql-questions/dates-in-sql)
......@@ -6,25 +6,40 @@ title: DatetimeSubtract
`datetimeSubtract` takes a datetime value and subtracts some unit of time from it. You might want to use this function when working with time series data that's marked by a "start" and an "end", such as sessions or subscriptions data.
| Syntax | Example |
|-------------------------------------------------------------------------------------------|-----------------------------------------------------------|
| `datetimeSubtract(column, amount, unit)` | `datetimeSubtract("March 25, 2021, 12:52:37", 1, "month")`|
| Takes a timestamp or date value and subtracts the specified number of time units from it. | `February 25, 2021, 12:52:37` |
| Syntax | Example |
|-------------------------------------------------------------------------------------------|---------------------------------------------|
| `datetimeSubtract(column, amount, unit)` | `datetimeSubtract("2021-03-25", 1, "month")`|
| Takes a timestamp or date value and subtracts the specified number of time units from it. | `2021-02-25` |
## Parameters
- Units can be any of: "year", "quarter", "month", "day", "hour", "second", or "millisecond".
- Amounts can be negative: `datetimeSubtract("March 25, 2021, 12:52:37", -1, "month")` will return `April 25, 2021, 12:52:37`.
`column` can be any of:
- The name of a timestamp column,
- a custom expression that returns a [datetime](#accepted-data-types), or
- a string in the format `"YYYY-MM-DD"` or `"YYYY-MM-DDTHH:MM:SS"` (as shown in the example above).
`unit` can be any of:
- "year"
- "quarter"
- "month"
- "day"
- "hour"
- "second"
- "millisecond"
`amount`:
- A whole number or a decimal number.
- May be a negative number: `datetimeSubtract("2021-03-25", -1, "month")` will return `2021-04-25`.
## Calculating a start date
Let's say you're planning a fun night out. You know it takes 30 minutes to get from place to place, and you need to figure out what time you have to leave to get to each of your reservations:
| Event | Arrive By | Depart At |
|---------|---------------------|---------------------|
| Drinks | 2022-11-12 18:30:00 | 2022-11-12 18:00:00 |
| Dinner | 2022-11-12 20:00:00 | 2022-11-12 19:30:00 |
| Dancing | 2022-11-13 00:00:00 | 2022-11-12 23:30:00 |
| Event | Arrive By | Depart At |
|---------|----------------------------|-----------------------------|
| Drinks | November 12, 2022 6:30 PM | November 12, 2022 6:00 PM |
| Dinner | November 12, 2022 8:00 PM | November 12, 2022 7:30 PM |
| Dancing | November 13, 2022 12:00 AM | November 12, 2022 11:30 PM |
Here, **Depart At** is a custom column with the expression:
......@@ -32,7 +47,24 @@ Here, **Depart At** is a custom column with the expression:
datetimeSubtract([Arrive By], 30, "minute")
```
You can use the [`between`](../expressions-list.md#between) or [`interval`](../expressions-list.md#interval) expressions to check if a given date falls between your start and end datetimes.
## Comparing a date to a window of time
To check if an existing datetime falls between your start and end datetimes, use [`between`](../expressions-list.md#between).
Unfortunately, Metabase doesn't currently support datetime functions like `today`. What if you want to check if today's date falls between **Arrive By** and **Depart At** in our [events example](#calculating-a-start-date)?
1. Ask your database admin if there's table in your database that stores datetimes for reporting (sometimes called a date dimension table).
2. Create a new question using the date dimension table, with a filter for "Today".
3. Turn the "Today" question into a [model](../../../data-modeling/models.md).
4. Create a [left join](../../query-builder/join.md) between **Events** and the "Today" model on `[Arrive By] <= [Today]` and `[Depart At] >= [Today]`.
The result should give you an **Today** column that's non-empty for events that are happening while the night is still young:
| Event | Arrive By | Depart At | Today |
|---------|----------------------------|-----------------------------|-----------------------------|
| Drinks | November 12, 2022 6:30 PM | November 12, 2022 6:00 PM | November 12, 2022 12:00 AM |
| Dinner | November 12, 2022 8:00 PM | November 12, 2022 7:30 PM | November 12, 2022 12:00 AM |
| Dancing | November 13, 2022 12:00 AM | November 12, 2022 11:30 PM | |
## Accepted data types
......@@ -44,26 +76,13 @@ You can use the [`between`](../expressions-list.md#between) or [`interval`](../e
| Boolean | ❌ |
| JSON | ❌ |
This table uses `timestamp` and `datetime` interchangeably---just make sure that your dates and times aren't stored as string or a number data types in your database.
## Limitations
We use "timestamp" and "datetime" to talk about any temporal data type that's supported by Metabase.
You can use `datetimeSubtract` to calculate relative dates given a column of date values, but unfortunately Metabase doesn't currently let you _generate_ a relative date (such as today's date).
If your timestamps are stored as strings or numbers in your database, an admin can [cast them to timestamps](../../../data-modeling/metadata-editing.md#casting-to-a-specific-data-type) from the Data Model page.
What if you want to check if today's date falls between **Arrive By** and **Depart At** in our [events example](#calculating-a-start-date)?
1. Ask your database admin if there's table in your database that stores datetimes for reporting (sometimes called a date dimension table).
2. Create a new question using the date dimension table, with a filter for "Today".
3. Turn the "Today" question into a model.
4. Create a left join between **Events** and the "Today" model on `[Arrive By] <= [Today]` and `[Depart At] >= [Today]`.
The result should give you an **Today** column that's non-empty for events that are happening while the night is still young:
## Limitations
| Event | Arrive By | Depart At | Today |
|---------|---------------------|---------------------|---------------------|
| Drinks | 2022-11-12 18:30:00 | 2022-11-12 18:00:00 | 2022-11-12 00:00:00 |
| Dinner | 2022-11-12 20:00:00 | 2022-11-12 19:30:00 | 2022-11-12 00:00:00 |
| Dancing | 2022-11-13 00:00:00 | 2022-11-12 23:30:00 | |
If you're using MongoDB, `datetimeSubtract` will only work on versions 5 and up.
## Related functions
......
......@@ -777,7 +777,9 @@ const helperTextStrings: HelpText[] = [
", [" +
t`source` +
"])",
description: t`Convert timezone of a date or timestamp column.`,
description: t`Convert timezone of a date or timestamp column.
We support tz database time zone names.
See the full list here: https://w.wiki/4Jx`,
example:
"convertTimezone([" + t`Created At` + '], "Asia/Ho_Chi_Minh", "UTC")',
args: [
......@@ -791,7 +793,7 @@ const helperTextStrings: HelpText[] = [
},
{
name: t`source`,
description: t`(Optional) The current timezone of your column. The default timezone is your report timezone.`,
description: t`The current time zone. Only required for timestamps with no time zone.`,
},
],
},
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment