From 361bfc35724aac207f7a013336e058704fbadf60 Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Wed, 22 Oct 2008 11:00:34 +0000
Subject: [PATCH] SQL:2008 alternative syntax for LIMIT/OFFSET: OFFSET num
 {ROW|ROWS} FETCH {FIRST|NEXT} [num] {ROW|ROWS} ONLY

---
 doc/src/sgml/ref/select.sgml         | 48 ++++++++++++++++++++++++----
 doc/src/sgml/ref/select_into.sgml    |  5 +--
 doc/src/sgml/ref/values.sgml         | 16 ++++++----
 src/backend/catalog/sql_features.txt | 18 +++++------
 src/backend/parser/gram.y            | 44 +++++++++++++++++++++++--
 src/backend/parser/keywords.c        |  4 +--
 6 files changed, 108 insertions(+), 27 deletions(-)

diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml
index f73ca6ed64..91a756b3ae 100644
--- a/doc/src/sgml/ref/select.sgml
+++ b/doc/src/sgml/ref/select.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.106 2008/10/07 19:27:04 tgl Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.107 2008/10/22 11:00:33 petere Exp $
 PostgreSQL documentation
 -->
 
@@ -30,7 +30,8 @@ SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replac
     [ { UNION | INTERSECT | EXCEPT } [ ALL ] <replaceable class="parameter">select</replaceable> ]
     [ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...] ]
     [ LIMIT { <replaceable class="parameter">count</replaceable> | ALL } ]
-    [ OFFSET <replaceable class="parameter">start</replaceable> ]
+    [ OFFSET <replaceable class="parameter">start</replaceable> [ ROW | ROWS ] ]
+    [ FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } ONLY ]
     [ FOR { UPDATE | SHARE } [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT ] [...] ]
 
 where <replaceable class="parameter">from_item</replaceable> can be one of:
@@ -150,7 +151,7 @@ and <replaceable class="parameter">with_query</replaceable> is:
 
     <listitem>
      <para>
-      If the <literal>LIMIT</literal> or <literal>OFFSET</literal>
+      If the <literal>LIMIT</literal> (or <literal>FETCH FIRST</literal>) or <literal>OFFSET</literal>
       clause is specified, the <command>SELECT</command> statement
       only returns a subset of the result rows. (See <xref
       linkend="sql-limit" endterm="sql-limit-title"> below.)
@@ -891,6 +892,24 @@ OFFSET <replaceable class="parameter">start</replaceable>
     class="parameter">count</replaceable> rows to be returned.
    </para>
 
+   <para>
+    SQL:2008 introduced a different syntax to achieve the same thing,
+    which PostgreSQL also supports.  It is:
+<synopsis>
+OFFSET <replaceable class="parameter">start</replaceable> { ROW | ROWS }
+FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } ONLY
+</synopsis>
+    Both clauses are optional, but if present
+    the <literal>OFFSET</literal> clause must come before
+    the <literal>FETCH</literal> clause.  <literal>ROW</literal>
+    and <literal>ROWS</literal> as well as <literal>FIRST</literal>
+    and <literal>NEXT</literal> are noise words that don't influence
+    the effects of these clauses.  When using expressions other than
+    constants for the offset or fetch count, parentheses will be
+    necessary in most cases.  If the fetch count is omitted, it
+    defaults to 1.
+   </para>    
+
    <para>
     When using <literal>LIMIT</>, it is a good idea to use an
     <literal>ORDER BY</> clause that constrains the result rows into a
@@ -1337,13 +1356,30 @@ SELECT distributors.* WHERE distributors.name = 'Westward';
    </para>
   </refsect2>
 
+  <refsect2>
+   <title><literal>LIMIT</literal> and <literal>OFFSET</literal></title>
+
+   <para>
+    The clauses <literal>LIMIT</literal> and <literal>OFFSET</literal>
+    are <productname>PostgreSQL</productname>-specific syntax, also
+    used by <productname>MySQL</productname>.  The SQL:2008 standard
+    has introduced the clauses <literal>OFFSET ... FETCH {FIRST|NEXT}
+    ...</literal> for the same functionality, as shown above
+    in <xref linkend="sql-limit" endterm="sql-limit-title">, and this
+    syntax is also used by <productname>IBM DB2</productname>.
+    (Applications written for <productname>Oracle</productname>
+    frequently use a workaround involving the automatically
+    generated <literal>rownum</literal> column, not available in
+    PostgreSQL, to implement the effects of these clauses.)
+   </para>
+  </refsect2>
+
   <refsect2>
    <title>Nonstandard Clauses</title>
 
    <para>
-    The clauses <literal>DISTINCT ON</literal>,
-    <literal>LIMIT</literal>, and <literal>OFFSET</literal> are not
-    defined in the SQL standard.
+    The clause <literal>DISTINCT ON</literal> is not defined in the
+    SQL standard.
    </para>
   </refsect2>
  </refsect1>
diff --git a/doc/src/sgml/ref/select_into.sgml b/doc/src/sgml/ref/select_into.sgml
index de9a86a878..cbe46cf763 100644
--- a/doc/src/sgml/ref/select_into.sgml
+++ b/doc/src/sgml/ref/select_into.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/select_into.sgml,v 1.41 2008/10/04 21:56:52 tgl Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/select_into.sgml,v 1.42 2008/10/22 11:00:34 petere Exp $
 PostgreSQL documentation
 -->
 
@@ -31,7 +31,8 @@ SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replac
     [ { UNION | INTERSECT | EXCEPT } [ ALL ] <replaceable class="parameter">select</replaceable> ]
     [ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...] ]
     [ LIMIT { <replaceable class="parameter">count</replaceable> | ALL } ]
-    [ OFFSET <replaceable class="parameter">start</replaceable> ]
+    [ OFFSET <replaceable class="parameter">start</replaceable> [ ROW | ROWS ] ]
+    [ FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } ONLY ]
     [ FOR { UPDATE | SHARE } [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT ] [...] ]
 </synopsis>
  </refsynopsisdiv>
diff --git a/doc/src/sgml/ref/values.sgml b/doc/src/sgml/ref/values.sgml
index 23b84d7820..ef605f818f 100644
--- a/doc/src/sgml/ref/values.sgml
+++ b/doc/src/sgml/ref/values.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/values.sgml,v 1.4 2007/02/01 00:28:19 momjian Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/values.sgml,v 1.5 2008/10/22 11:00:34 petere Exp $
 PostgreSQL documentation
 -->
 
@@ -23,7 +23,8 @@ PostgreSQL documentation
 VALUES ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) [, ...]
     [ ORDER BY <replaceable class="parameter">sort_expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [, ...] ]
     [ LIMIT { <replaceable class="parameter">count</replaceable> | ALL } ]
-    [ OFFSET <replaceable class="parameter">start</replaceable> ]
+    [ OFFSET <replaceable class="parameter">start</replaceable> [ ROW | ROWS ] ]
+    [ FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } ONLY ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -48,8 +49,10 @@ VALUES ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) [, ..
   <para>
    Within larger commands, <command>VALUES</> is syntactically allowed
    anywhere that <command>SELECT</> is.  Because it is treated like a
-   <command>SELECT</> by the grammar, it is possible to use the <literal>ORDER
-   BY</>, <literal>LIMIT</>, and <literal>OFFSET</> clauses with a
+   <command>SELECT</> by the grammar, it is possible to use
+   the <literal>ORDER BY</>, <literal>LIMIT</> (or
+   equivalently <literal>FETCH FIRST</literal>),
+   and <literal>OFFSET</> clauses with a
    <command>VALUES</> command.
   </para>
  </refsect1>
@@ -227,9 +230,10 @@ WHERE ip_address IN (VALUES('192.168.0.1'::inet), ('192.168.0.10'), ('192.168.1.
   <title>Compatibility</title>
 
   <para>
-   <command>VALUES</command> conforms to the SQL standard, except that
+   <command>VALUES</command> conforms to the SQL standard.
    <literal>LIMIT</literal> and <literal>OFFSET</literal> are
-   <productname>PostgreSQL</productname> extensions.
+   <productname>PostgreSQL</productname> extensions; see also
+   under <xref linkend="sql-select" endterm="sql-select-title">.
   </para>
  </refsect1>
 
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 4c50a22a0a..b90856fafb 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -319,15 +319,15 @@ F851	<order by clause> in subqueries			YES
 F852	Top-level <order by clause> in views			YES	
 F855	Nested <order by clause> in <query expression>			YES	
 F856	Nested <fetch first clause> in <query expression>			YES	
-F857	Top-level <fetch first clause> in <query expression>			NO	same as LIMIT
-F858	<fetch first clause> in subqueries			NO	same as LIMIT
-F859	Top-level <fetch first clause> in views			NO	same as LIMIT
-F860	<fetch first row count> in <fetch first clause>			NO	same as LIMIT
-F861	Top-level <result offset clause> in <query expression>			NO	same as OFFSET
-F862	<result offset clause> in subqueries			NO	same as OFFSET
-F863	Nested <result offset clause> in <query expression>			NO	same as OFFSET
-F864	Top-level <result offset clause> in views			NO	same as OFFSET
-F865	<offset row count> in <result offset clause>			NO	same as OFFSET
+F857	Top-level <fetch first clause> in <query expression>			YES	
+F858	<fetch first clause> in subqueries			YES	
+F859	Top-level <fetch first clause> in views			YES	
+F860	<fetch first row count> in <fetch first clause>			YES	
+F861	Top-level <result offset clause> in <query expression>			YES	
+F862	<result offset clause> in subqueries			YES	
+F863	Nested <result offset clause> in <query expression>			YES	
+F864	Top-level <result offset clause> in views			YES	
+F865	<offset row count> in <result offset clause>			YES	
 S011	Distinct data types			NO	
 S011	Distinct data types	01	USER_DEFINED_TYPES view	NO	
 S023	Basic structured types			NO	
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index aa5f33b411..3ab62b23cb 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -11,7 +11,7 @@
  *
  *
  * IDENTIFICATION
- *	  $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.627 2008/10/21 08:38:15 petere Exp $
+ *	  $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.628 2008/10/22 11:00:34 petere Exp $
  *
  * HISTORY
  *	  AUTHOR			DATE			MAJOR EVENT
@@ -308,6 +308,8 @@ static TypeName *TableFuncTypeName(List *columns);
 %type <objtype>	reindex_type drop_type comment_type
 
 %type <node>	fetch_direction select_limit_value select_offset_value
+				select_offset_value2 opt_select_fetch_first_value
+%type <ival>	row_or_rows first_or_next
 
 %type <list>	OptSeqOptList SeqOptList
 %type <defelt>	SeqOptElem
@@ -6579,6 +6581,13 @@ select_limit:
 							 errhint("Use separate LIMIT and OFFSET clauses."),
 							 scanner_errposition(@1)));
 				}
+			/* SQL:2008 syntax variants */
+			| OFFSET select_offset_value2 row_or_rows
+				{ $$ = list_make2($2, NULL); }
+			| FETCH first_or_next opt_select_fetch_first_value row_or_rows ONLY
+				{ $$ = list_make2(NULL, $3); }
+			| OFFSET select_offset_value2 row_or_rows FETCH first_or_next opt_select_fetch_first_value row_or_rows ONLY
+				{ $$ = list_make2($2, $6); }
 		;
 
 opt_select_limit:
@@ -6596,10 +6605,40 @@ select_limit_value:
 				}
 		;
 
+/*
+ * Allowing full expressions without parentheses causes various parsing
+ * problems with the trailing ROW/ROWS key words.  SQL only calls for
+ * constants, so we allow the rest only with parentheses.
+ */
+opt_select_fetch_first_value:
+			SignedIconst		{ $$ = makeIntConst($1, @1); }
+			| '(' a_expr ')'	{ $$ = $2; }
+			| /*EMPTY*/		{ $$ = makeIntConst(1, -1); }
+		;
+
 select_offset_value:
 			a_expr									{ $$ = $1; }
 		;
 
+/*
+ * Again, the trailing ROW/ROWS in this case prevent the full expression
+ * syntax.  c_expr is the best we can do.
+ */
+select_offset_value2:
+			c_expr									{ $$ = $1; }
+		;
+
+/* noise words */
+row_or_rows:
+			ROW		{ $$ = 0; }
+			| ROWS		{ $$ = 0; }
+
+/* noise words */
+first_or_next:
+			FIRST_P		{ $$ = 0; }
+			| NEXT		{ $$ = 0; }
+
+
 group_clause:
 			GROUP_P BY expr_list					{ $$ = $3; }
 			| /*EMPTY*/								{ $$ = NIL; }
@@ -9218,6 +9257,7 @@ Sconst:		SCONST									{ $$ = $1; };
 RoleId:		ColId									{ $$ = $1; };
 
 SignedIconst: ICONST								{ $$ = $1; }
+			| '+' ICONST							{ $$ = + $2; }
 			| '-' ICONST							{ $$ = - $2; }
 		;
 
@@ -9351,7 +9391,6 @@ unreserved_keyword:
 			| EXPLAIN
 			| EXTERNAL
 			| FAMILY
-			| FETCH
 			| FIRST_P
 			| FORCE
 			| FORWARD
@@ -9641,6 +9680,7 @@ reserved_keyword:
 			| END_P
 			| EXCEPT
 			| FALSE_P
+			| FETCH
 			| FOR
 			| FOREIGN
 			| FROM
diff --git a/src/backend/parser/keywords.c b/src/backend/parser/keywords.c
index 7c6aa71572..608e80e0f5 100644
--- a/src/backend/parser/keywords.c
+++ b/src/backend/parser/keywords.c
@@ -11,7 +11,7 @@
  *
  *
  * IDENTIFICATION
- *	  $PostgreSQL: pgsql/src/backend/parser/keywords.c,v 1.203 2008/10/21 08:38:15 petere Exp $
+ *	  $PostgreSQL: pgsql/src/backend/parser/keywords.c,v 1.204 2008/10/22 11:00:34 petere Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -166,7 +166,7 @@ const ScanKeyword ScanKeywords[] = {
 	{"extract", EXTRACT, COL_NAME_KEYWORD},
 	{"false", FALSE_P, RESERVED_KEYWORD},
 	{"family", FAMILY, UNRESERVED_KEYWORD},
-	{"fetch", FETCH, UNRESERVED_KEYWORD},
+	{"fetch", FETCH, RESERVED_KEYWORD},
 	{"first", FIRST_P, UNRESERVED_KEYWORD},
 	{"float", FLOAT_P, COL_NAME_KEYWORD},
 	{"for", FOR, RESERVED_KEYWORD},