|
1 | 1 | ---
|
2 | 2 | {
|
3 |
| - "title": "HOUR_CEIL", |
4 |
| - "language": "en" |
| 3 | + "title": "HOUR_CEIL", |
| 4 | + "language": "en" |
5 | 5 | }
|
6 | 6 | ---
|
7 | 7 |
|
8 | 8 | ## Description
|
9 | 9 |
|
10 |
| -Converts the date to the nearest rounded-up timestamp of the specified time interval period. |
| 10 | +The HOUR_CEIL function rounds up the input datetime value to the nearest moment of the specified hour period. For example, if the period is specified as 5 hours, the function will adjust the input time to the next hour mark within that period (if the input time is already at the period origin, it remains unchanged). |
| 11 | + |
| 12 | +Date calculation formula: |
| 13 | +HOUR_CEIL(`<date_or_time_expr>`, `<period>`, `<origin>`) = min{`<origin>` + k × `<period>` × hour | k ∈ ℤ ∧ `<origin>` + k × `<period>` × hour ≥ `<date_or_time_expr>`} |
| 14 | + |
| 15 | +K represents the number of periods required from the baseline time to reach the target time. |
11 | 16 |
|
12 | 17 | ## Syntax
|
13 | 18 |
|
14 | 19 | ```sql
|
15 |
| -HOUR_CEIL(<datetime>) |
16 |
| -HOUR_CEIL(<datetime>, <origin>) |
17 |
| -HOUR_CEIL(<datetime>, <period>) |
18 |
| -HOUR_CEIL(<datetime>, <period>, <origin>) |
| 20 | +HOUR_CEIL(`<date_or_time_expr>`) |
| 21 | +HOUR_CEIL(`<date_or_time_expr>`, `<origin>`) |
| 22 | +HOUR_CEIL(`<date_or_time_expr>`, `<period>`) |
| 23 | +HOUR_CEIL(`<date_or_time_expr>`, `<period>`, `<origin>`) |
19 | 24 | ```
|
20 | 25 |
|
21 | 26 | ## Parameters
|
22 | 27 |
|
23 | 28 | | Parameter | Description |
|
24 | 29 | | -- | -- |
|
25 |
| -| `<datetime>` | A valid date expression | |
26 |
| -| `<period>`| Specifies how many hours make up each period| |
27 |
| -| `<origin>` | The starting point of time. If not provided, the default is 0001-01-01T00:00:00 | |
| 30 | +| `<date_or_time_expr>` | A valid date expression that supports datetime and date types. Date type will be converted to the start of the day at 00:00:00. For specific datetime/date formats, please refer to [datetime conversion](../../../../../current/sql-manual/basic-element/sql-data-types/conversion/datetime-conversion) and [date conversion](../../../../../current/sql-manual/basic-element/sql-data-types/conversion/date-conversion) | |
| 31 | +| `<period>` | Optional parameter that specifies the period length (unit: hours), must be a positive integer (such as 1, 3, 5). Default value is 1, representing one period every 1 hour | |
| 32 | +| `<origin>` | The starting time origin, supports datetime and date types. If not provided, the default is 0001-01-01T00:00:00 | |
28 | 33 |
|
29 | 34 | ## Return Value
|
30 | 35 |
|
31 |
| -Returns the nearest rounded-up timestamp of the specified time interval period. |
| 36 | +Returns a DATETIME type value representing the nearest period moment after rounding up. |
| 37 | + |
| 38 | +- If the input period is a non-positive integer, returns an error. |
| 39 | +- If any parameter is NULL, the result returns NULL. |
| 40 | +- If origin or datetime has scale, the returned result has scale. |
| 41 | +- If the calculation result exceeds the maximum datetime range 9999-12-31 23:59:59, returns an error. |
| 42 | + |
32 | 43 |
|
33 | 44 | ## Examples
|
34 | 45 |
|
35 | 46 | ```sql
|
36 |
| -select hour_ceil("2023-07-13 22:28:18", 5); |
37 |
| -``` |
38 | 47 |
|
39 |
| -```text |
40 |
| -+------------------------------------------------------------+ |
41 |
| -| hour_ceil(cast('2023-07-13 22:28:18' as DATETIMEV2(0)), 5) | |
42 |
| -+------------------------------------------------------------+ |
43 |
| -| 2023-07-14 02:00:00 | |
44 |
| -+------------------------------------------------------------+ |
| 48 | +-- Round up with a 5-hour period |
| 49 | +mysql> select hour_ceil("2023-07-13 22:28:18", 5); |
| 50 | ++-------------------------------------+ |
| 51 | +| hour_ceil("2023-07-13 22:28:18", 5) | |
| 52 | ++-------------------------------------+ |
| 53 | +| 2023-07-13 23:00:00 | |
| 54 | ++-------------------------------------+ |
| 55 | + |
| 56 | +-- Using 2023-07-13 08:00 as the origin, divide by 4-hour periods |
| 57 | +mysql> select hour_ceil('2023-07-13 19:30:00', 4, '2023-07-13 08:00:00') as custom_origin; |
| 58 | ++----------------------------+ |
| 59 | +| custom_origin | |
| 60 | ++----------------------------+ |
| 61 | +| 2023-07-13 20:00:00 | |
| 62 | ++----------------------------+ |
| 63 | + |
| 64 | +-- Input date type will be converted to the start time 00:00:00 of the corresponding date |
| 65 | +mysql> select hour_ceil('2023-07-13 00:30:00', 6, '2023-07-13'); |
| 66 | ++---------------------------------------------------+ |
| 67 | +| hour_ceil('2023-07-13 00:30:00', 6, '2023-07-13') | |
| 68 | ++---------------------------------------------------+ |
| 69 | +| 2023-07-13 06:00:00 | |
| 70 | ++---------------------------------------------------+ |
| 71 | + |
| 72 | +-- If exactly at the edge of a period, return the input datetime |
| 73 | +select hour_ceil('2023-07-13 01:00:00'); |
| 74 | ++----------------------------------+ |
| 75 | +| hour_ceil('2023-07-13 01:00:00') | |
| 76 | ++----------------------------------+ |
| 77 | +| 2023-07-13 01:00:00 | |
| 78 | ++----------------------------------+ |
| 79 | + |
| 80 | +-- If origin or datetime has scale, the returned result has scale |
| 81 | +mysql> select hour_ceil('2023-07-13 19:30:00', 4, '2023-07-13 08:00:00.123') ; |
| 82 | ++----------------------------------------------------------------+ |
| 83 | +| hour_ceil('2023-07-13 19:30:00', 4, '2023-07-13 08:00:00.123') | |
| 84 | ++----------------------------------------------------------------+ |
| 85 | +| 2023-07-13 20:00:00.123 | |
| 86 | ++----------------------------------------------------------------+ |
| 87 | + |
| 88 | +mysql> select hour_ceil('2023-07-13 19:30:00.123', 4, '2023-07-13 08:00:00') ; |
| 89 | ++----------------------------------------------------------------+ |
| 90 | +| hour_ceil('2023-07-13 19:30:00.123', 4, '2023-07-13 08:00:00') | |
| 91 | ++----------------------------------------------------------------+ |
| 92 | +| 2023-07-13 20:00:00.000 | |
| 93 | ++----------------------------------------------------------------+ |
| 94 | + |
| 95 | +-- If calculation result exceeds maximum datetime range 9999-12-31 23:59:59, return NULL |
| 96 | +select hour_ceil("9999-12-31 22:28:18", 6); |
| 97 | +ERROR 1105 (HY000): errCode = 2, detailMessage = (10.16.10.3)[E-218]Operation hour_ceil of 9999-12-31 22:28:18, 6 out of range |
| 98 | + |
| 99 | +-- If period is less than or equal to 0, return error |
| 100 | +mysql> select hour_ceil("2023-07-13 22:28:18", 0); |
| 101 | +ERROR 1105 (HY000): errCode = 2, detailMessage = (10.16.10.3)[INVALID_ARGUMENT]Operation hour_ceil of 2023-07-13 22:28:18, 0 input wrong parameters, period can not be negative or zero |
| 102 | + |
| 103 | +-- If any input parameter is NULL, return NULL |
| 104 | +mysql> select hour_ceil(null, 3) as null_input; |
| 105 | ++------------+ |
| 106 | +| null_input | |
| 107 | ++------------+ |
| 108 | +| NULL | |
| 109 | ++------------+ |
| 110 | + |
| 111 | +mysql> select hour_ceil("2023-07-13 22:28:18", NULL); |
| 112 | ++----------------------------------------+ |
| 113 | +| hour_ceil("2023-07-13 22:28:18", NULL) | |
| 114 | ++----------------------------------------+ |
| 115 | +| NULL | |
| 116 | ++----------------------------------------+ |
| 117 | + |
| 118 | +mysql> select hour_ceil("2023-07-13 22:28:18", 5,NULL); |
| 119 | ++------------------------------------------+ |
| 120 | +| hour_ceil("2023-07-13 22:28:18", 5,NULL) | |
| 121 | ++------------------------------------------+ |
| 122 | +| NULL | |
| 123 | ++------------------------------------------+ |
45 | 124 | ```
|
0 commit comments