8
0
mirror of https://github.com/FirebirdSQL/firebird.git synced 2025-01-22 20:43:02 +01:00
firebird-mirror/doc/sql.extensions
2016-09-01 13:28:01 -03:00
..
README.aggregate_tracking Please give some comments 2003-07-29 00:55:34 +00:00
README.alternate_string_quoting.txt - External Engines implementation. 2009-10-21 00:42:38 +00:00
README.autonomous_transactions.txt Put in the tree the docs previo usly done in the wiki as per Dmitry request 2008-06-12 01:02:00 +00:00
README.builtin_functions.txt Added support for system privileges 2016-05-31 20:07:08 +03:00
README.case update readme's with method used for determing result data type 2005-02-01 23:55:56 +00:00
README.coalesce update readme's with method used for determing result data type 2005-02-01 23:55:56 +00:00
README.column_type_psql.txt The merge is being fixed. 2008-01-16 13:38:46 +00:00
README.common_table_expressions Fixed some warnings 2009-04-03 10:49:07 +00:00
README.context_variables Fixed docs. 2007-12-04 08:29:10 +00:00
README.context_variables2 Simplify migration for old databases affected by changes in 2016-03-27 11:20:27 +03:00
README.cumulative_roles.txt Fixed misprint 2016-05-27 17:26:07 +03:00
README.current_time Typo. 2005-10-21 09:49:22 +00:00
README.cursor_variables.txt Fixed CORE-4488 - Wrong results of FOR SELECT <L> FROM <T> AS CURSOR <C> and table <T> is modified inside cursor's begin...end block. 2014-07-21 02:37:58 +00:00
README.cursors Documentation for CORE-4403 - Allow referencing cursors as record variables in PSQL. 2014-06-16 16:04:55 +00:00
README.data_type_results_of_aggregations.txt Corrections. 2007-04-09 14:39:03 +00:00
README.data_types More changes related to CORE-5167. 2016-04-13 12:47:35 -03:00
README.db_triggers.txt Misc. 2007-12-04 08:23:13 +00:00
README.ddl_access.txt Implemented CORE-4538: Access rights for CREATE DATABASE operator 2014-09-02 16:55:14 +00:00
README.ddl_triggers.txt Improvement CORE-4923 - Add ability to track domains rename in DDL triggers. 2015-09-02 16:24:31 +00:00
README.ddl.txt Misc 2016-06-01 12:00:48 +03:00
README.default_parameters Correctly written my name and e-mail 2008-05-13 07:26:32 +00:00
README.derived_tables.txt update readme's with method used for determing result data type 2005-02-01 23:55:56 +00:00
README.distinct More docs. 2005-01-22 21:03:03 +00:00
README.domains_psql.txt The merge is being fixed. 2008-01-16 13:38:46 +00:00
README.exception_handling Correction - thanks to Simonov Denis. 2015-04-30 15:24:12 +00:00
README.execute_block Correctly written my name and e-mail 2008-05-13 07:26:32 +00:00
README.execute_statement Misc, adding example. 2006-07-31 07:42:47 +00:00
README.execute_statement2 Misc 2011-02-18 00:52:10 +00:00
README.explicit_locks Fix typo 2003-07-31 11:54:46 +00:00
README.expression_indices Fixed some warnings 2009-04-03 10:49:07 +00:00
README.global_temporary_tables Misc 2009-04-04 16:28:33 +00:00
README.hex_literals.txt Documentation for hexadecimal numeric and binary strings literals 2008-05-15 15:28:32 +00:00
README.identity_columns.txt Misc. 2014-05-24 06:12:52 +00:00
README.iif More docs. 2005-01-22 21:13:15 +00:00
README.isc_info_xxx Misc 2009-02-13 21:08:56 +00:00
README.joins.txt Doc. for new join types 2007-05-03 01:32:08 +00:00
README.keywords Updated the docs for Beta 2. 2015-06-23 22:00:25 +00:00
README.leave_labels Added some docs. 2005-01-06 18:32:22 +00:00
README.length Merge INTL branch into HEAD 2005-05-27 22:45:31 +00:00
README.linger Implemented CORE-4263: Database linger 2013-11-14 16:16:24 +00:00
README.list Updated LIST documentation - thanks to Maycon Ferraça 2007-05-09 15:23:33 +00:00
README.mapping.html Fixed doc - thanks to Helen 2016-08-17 13:13:38 +03:00
README.merge.txt Finish MERGE improvements documentation (CORE-2005, CORE-3020, CORE-3639). 2013-04-26 15:29:48 +00:00
README.null_value Placeholders for further docs. 2005-01-22 21:18:33 +00:00
README.nullif update readme's with method used for determing result data type 2005-02-01 23:55:56 +00:00
README.offset_fetch.txt CORE-4526 Support for SQL:2008 OFFSET and FETCH clauses 2014-11-29 15:39:59 +00:00
README.order_by_expressions_nulls Corrections for v2.0 and above. 2007-07-03 12:10:22 +00:00
README.packages.txt Correction. 2013-05-13 15:56:29 +00:00
README.plan Minor fixes. 2005-01-25 06:24:30 +00:00
README.PSQL_stack_trace.txt Correctly written my name and e-mail 2008-05-13 07:26:32 +00:00
README.regr_functions.txt Misc. 2015-03-31 02:10:38 +00:00
README.returning Docs. 2013-04-26 15:52:23 +00:00
README.rows CORE-4526 Support for SQL:2008 OFFSET and FETCH clauses 2014-11-29 15:39:59 +00:00
README.savepoints Added docs for savepoints 2003-07-29 11:33:26 +00:00
README.scrollable_cursors.txt Fixed a mistake. 2015-03-21 05:15:25 +00:00
README.select_expressions Corrections, thanks to Claudio. 2006-01-10 07:59:54 +00:00
README.sequence_generators Minor fixes. 2005-01-25 06:24:30 +00:00
README.set_role Added doc 2014-11-14 08:24:43 +00:00
README.set_transaction.txt Add documentation for the extra options exposed through the DSQL's SET TRANSACTION command. This functionality exists already using TPB's. 2005-12-01 02:34:47 +00:00
README.similar_to.txt 1) Fixed CORE-1935 – SIMILAR TO character classes are incorrectly recognized. 2008-06-14 02:17:20 +00:00
README.statistical_functions.txt Feature CORE-4717 - Aggregate statistical functions COVAR_SAMP, COVAR_POP and CORR - contributed by Hajime Nakagami. 2015-03-23 02:55:42 +00:00
README.subroutines.txt Document subroutines (CORE-1288 and CORE-3626). 2013-05-13 15:56:49 +00:00
README.substring_similar.txt Misc. 2013-05-21 21:43:39 +00:00
README.trim Merge INTL branch into HEAD 2005-05-27 22:45:31 +00:00
README.universal_triggers Fixed typos. 2005-12-03 11:09:39 +00:00
README.update_or_insert Fixed doc. mismatch reported by Paul Vinkenoog 2010-09-10 01:59:19 +00:00
README.user_management Fixed docs - thanks to Adriano 2016-03-28 12:03:26 +03:00
README.view_updates Placeholders for further docs. 2005-01-22 21:18:33 +00:00
README.window_functions.md Convert Window Functions README to markdown. 2016-09-01 13:28:01 -03:00

Window Functions

By the SQL specification, window functions (also know as analytical functions) are a kind of aggregation, but which does not "filter" the result set of a query. The aggregated data is mixed with the query result set.

That sort of functions are used with the OVER clause. Window functions may appear only in the select list or the order by clause of a query.

Additional to the OVER clause, Firebird window functions may be partitioned and ordered.

Syntax:

<window function> ::= <window function name>([<expr> [, <expr> ...]]) OVER (
  [PARTITION BY <expr> [, <expr> ...]]
  [ORDER BY <expr> [<direction>] [<nulls placement>] [, <expr> [<direction>] [<nulls placement>] ...]
)

<direction> ::= {ASC | DESC}

<nulls placement> ::= NULLS {FIRST | LAST}

1. Aggregate functions used as window functions

All aggregate functions may be used as window functions, adding the OVER clause. Imagine a table EMPLOYEE with columns ID, NAME and SALARY, and the need to show each employee with his respective salary and the percentage of his salary over the payroll. With a "normal" query, this is possible in the following manner:

select
    id,
    department,
    salary,
    salary / (select sum(salary) from employee) percentage
  from employee
  order by id;

Results:

id department salary percentage
1 R & D 10.00 0.2040
2 SALES 12.00 0.2448
3 SALES 8.00 0.1632
4 R & D 9.00 0.1836
5 R & D 10.00 0.2040

It's necessary to repeat the query in a subquery and wait so much to see the results, specially if EMPLOYEE is a complex view.

The same query could be specified in much more elegant and faster way using a window function:

select
    id,
    department,
    salary,
    salary / sum(salary) over () percentage
  from employee
  order by id;

Here, sum(salary) over () is computed with the sum of all SALARY from the query (the employee table).

2. Partitioning

Like aggregate functions, that may operate alone or in relation to a group, window functions may also operate on a group, which is called "partition". Its syntax is:

<window function name>(...) OVER (PARTITION BY <expr> [, <expr> ...])

When aggregation is done over a group, it could produce more than one row. So the result set generated by a partition is joined with the main query using the same expression list of the partition.

Continuing the employee example, instead of get the percentage of the employee salary over all employees, we would like to get the percentage based only on the employees in the same department:

select
    id,
    department,
    salary,
    salary / sum(salary) over (partition by department) percentage
  from employee
  order by id;

Results:

id department salary percentage
1 R & D 10.00 0.3448
2 SALES 12.00 0.6000
3 SALES 8.00 0.4000
4 R & D 9.00 0.3103
5 R & D 10.00 0.3448

3. Ordering

The ORDER BY sub-clause can be used with or without partitions, and used with the standard aggregate functions, make them return the partial aggregations as the records are being processed. Example:

select
    id,
    salary,
    sum(salary) over (order by salary) running_salary
  from employee
  order by salary;

The result set produced will be:

id salary running_salary
3 8.00 8.00
4 9.00 17.00
1 10.00 37.00
5 10.00 37.00
2 12.00 49.00

Then running_salary returns the partial/accumulated (or running) aggregation (of the SUM function). It may appear strange that 37.00 is repeated for the ids 1 and 5, but that is how it should work. The ORDER BY keys are grouped together and the aggregation is computed once (but summing the two 10.00). To avoid this, you can add the ID field to the end of the ORDER BY clause.

It's possible to use multiple windows with different orders, and ORDER BY parts like ASC / DESC and NULLS FIRST / NULLS LAST.

With a partition, ORDER BY works the same way, but at each partition boundary the aggregation is reset.

All aggregation functions are usable with ORDER BY, except the LIST function.

4. Exclusive window functions

Beyond aggregate functions, there is also exclusive window functions, currently divided in ranking and navigational categories.

Both set of functions can be used with/without partition/ordering, but the usage does not make much sense without ordering.

4.1 Ranking functions

Syntax:

<ranking window function> ::=
    DENSE_RANK() |
    RANK() |
    PERCENT_RANK() |
    CUME_DIST() |
    NTILE(<expr>) |
    ROW_NUMBER()

The rank functions compute the ordinal rank of a row within the window partition. In this category are the functions: DENSE_RANK, RANK and ROW_NUMBER.

With these functions, one can create different type of incremental counters. Think about SUM(1) OVER (ORDER BY SALARY), these functions do this type of thing, but all of them in different ways. Following is an example query, also comparing with the SUM behavior.

select
    id,
    salary,
    dense_rank() over (order by salary),
    rank() over (order by salary),
    percent_rank() over (order by salary),
    cume_dist() over (order by salary),
    ntile(3) over (order by salary),
    row_number() over (order by salary),
    sum(1) over (order by salary)
  from employee
  order by salary;

And the result set:

id salary dense_rank rank percent_rank cume_dist ntile row_number sum
3 8.00 1 1 0.000000000000000 0.2000000000000000 1 1 1
4 9.00 2 2 0.250000000000000 0.4000000000000000 1 2 2
1 10.00 3 3 0.500000000000000 0.8000000000000000 2 3 4
5 10.00 3 3 0.500000000000000 0.8000000000000000 2 4 4
2 12.00 4 5 1.000000000000000 1.0000000000000000 3 5 5

The difference between DENSE_RANK and RANK is that there is a gap related to duplicate rows (in relation to the window ordering) only in RANK. DENSE_RANK continues assigning sequential numbers after the duplicate salary. On the other hand, ROW_NUMBER always assigns sequential numbers, even when there is duplicate values.

PERCENT_RANK is a ratio of RANK to group count.

CUME_DIST is cumulative distribution of a value in a group.

NTILE distributes the rows into a specified number of groups. NTILE argument is restricted to integral positive literal, variable (:var) and DSQL parameter (?).

4.2 Navigational functions

Syntax:

<navigational window function> ::=
    FIRST_VALUE(<expr>) |
    LAST_VALUE(<expr>) |
    NTH_VALUE(<expr>, <offset>) [FROM FIRST | FROM LAST] |
    LAG(<expr> [ [, <offset> [, <default> ] ] ) |
    LEAD(<expr> [ [, <offset> [, <default> ] ] )

The navigational functions gets the simple (non-aggregated) value of an expression from another row (inside the same partition) of the query.

It's important to note that FIRST_VALUE, LAST_VALUE and NTH_VALUE also operates on a window frame, and Firebird is currently always framing from the first to the current (and not the last) row of the partition. This is likely to get strange results for NTH_VALUE and specially LAST_VALUE.

select
    id,
    salary,
    first_value(salary) over (order by salary),
    last_value(salary) over (order by salary),
    nth_value(salary, 2) over (order by salary),
    lag(salary) over (order by salary),
    lead(salary) over (order by salary)
  from employee
  order by salary;

And the result set:

id salary first_value last_value nth_value lag lead
3 8.00 8.00 8.00 <null> <null> 9.00
4 9.00 8.00 9.00 9.00 8.00 10.00
1 10.00 8.00 10.00 9.00 9.00 10.00
5 10.00 8.00 10.00 9.00 10.00 12.00
2 12.00 8.00 12.00 9.00 10.00 <null>

FIRST_VALUE and LAST_VALUE gets respectively the first and last value of the ordered partition.

NTH_VALUE gets the n-th value, starting from the first (default) or the last record, from the ordered partition. If offset is 1 from first, it's equivalent to FIRST_VALUE. If offset is 1 from last, it's equivalent to LAST_VALUE.

LAG and LEAD get the value within a distance respect to the current row and the offset (which defaults to 1) passed. In the case the offset points to outside of the partition, the default parameter (which defaults to NULL) is returned. LAG looks for a preceding row, and LEAD for a following row.

Author: Adriano dos Santos Fernandes