Can I use… over(… groups between …)


2005200720092011201320152017201910.15.2.0Apache Derby2.0BigQuery11.5Db2 (LUW)1.4.199H210.5.4MariaDB8.0.20MySQL19cOracle DB11PostgreSQL2019SQL Server3.28.0SQLite

The over accepts groups framing, which limits the scope of the window function to the rows between the specified number of distinct values int the order by keys.

SELECT *, COUNT(*) OVER(ORDER BY val
                       GROUPS BETWEEN 1 PRECEDING
                                  AND CURRENT ROW)
  FROM …

Returns an additional column with row count of the rows between all rows that have the next smaller value in the order by key (1 preceding) and all rows that have the same value as the current row in the order by key.

ORDER BY valGROUPSBETWEEN 1 PRECEDINGgroups betwAND CURRENT ROWval55.5667current 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.

Normative References

The groups framing is defined in ISO/IEC 9075:2016-2 as part of optional feature T620.

About the Author

Photo of Markus Winand

Markus Winand is the SQL Renaissance Ambassador. He is on a mission to introduce developers to the evolution of SQL in the 21st century. Markus can be hired as trainer, speaker and consultant via winand.at.

Buy his Book on Amazon

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

The essence of SQL tuning in 200 pages

Buy on Amazon
(paperback only)

Paperback and PDF also available at Markus’ store.

Hire Markus

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

“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