Can I use… over(… range between …) (datetime)


Apache DerbyBigQueryDb2 (LUW)H2MariaDBMySQLOracle DBPostgreSQLSQL ServerSQLite20072009201120132015201720192021⚠ 3.25.0 - 3.42.0ab⊘ 3.5.7 - 3.23.1⚠ 2012 - 2022ab⊘ 2008R2✓ 11+ab⚠ 8.4 - 10ab⊘ 8.3✓ 11gR1+✓ 8.0.11+⊘ 5.0 - 5.7⊘ 10.2 - 10.11b⊘ 5.1 - 10.1✓ 1.4.198+⊘ 1.4.191 - 1.4.197⚠ 9.7 - 11.5.8ab⚠ 2.0a⊘ 2.0b⊘ 10.15.1.3 - 10.16.1.1
  1. Only with unbounded and current row — not with interval distance as shown below
  2. Alternative: As Numeric distances work you can convert the datetime to a numeric representation and use this

The over accepts range framing, which limits the scope of the window functions to the rows between the specified range of values relative to the value of the current row.

SELECT *, COUNT(*) OVER(ORDER BY dt
                        RANGE BETWEEN INTERVAL '1' DAY PRECEDING
                                  AND CURRENT ROW)
  FROM …

Returns an additional column with the row count of the rows that have the order by value up to 1 day less than the current row (interval '1' day preceding) and all rows that hat the same order by value as the current row (current row).

dt2020-08-132020-08-142020-08-152020-08-152020-08-17ORDER BY dtRANGEBETWEEN INTERVAL '1' DAY PRECEDINGrange betwAND CURRENT ROWcurrent row

Meaningful framing requires an order by clause in over as well. Note that this order by clause does not necessarily affect the order of rows in the final result. If you want the result in a specific order, add an order by clause at the outermost query level.

Note that some systems that support over(… range between …) for numeric sort keys don’t support it on temporal data types.

Normative References

The over clause, including range between with a timestamp order by key, is defined in ISO/IEC 9075:2016-2 as part of optional feature T611, “Elementary OLAP operations”.

You can’t catch up on 20 years of SQL evolution in one day. Subscribe the newsletter via E-Mail, Twitter or RSS to gradually catch up and to keep modern-⁠sql.com on your radar.

About the Author

Photo of Markus Winand

Markus Winand provides insights into SQL and shows how different systems support it at modern-sql.com. Previously he made use-the-index-luke.com, which is still actively maintained. Markus can be hired as trainer, speaker and consultant via winand.at.

Buy the Book

Cover of “SQL Performance Explained”: Squirrel running on grass

The essence of SQL tuning in 200 pages

Buy now!
(paperback and/or PDF)

Paperback also available at Amazon.com.

Hire Markus

Markus offers SQL training and consulting for developers working at companies of all sizes.
Learn more »

Connect with Markus Winand

Markus Winand on LinkedInMarkus Winand on XINGMarkus Winand on Twitter
“modern SQL” by Markus Winand is licensed under a Creative Commons Attribution-Noncommercial-No Derivative Works 3.0 Unported License.
Legal | Contact | NO WARRANTY | Trademarks | Privacy and GDPR | CC-BY-NC-ND 3.0 license