diff --git a/src/test/regress/expected/tsrf.out b/src/test/regress/expected/tsrf.out
new file mode 100644
index 0000000000000000000000000000000000000000..983ce17c83911c416f204c7c3fb1cea21492c40e
--- /dev/null
+++ b/src/test/regress/expected/tsrf.out
@@ -0,0 +1,501 @@
+--
+-- tsrf - targetlist set returning function tests
+--
+-- simple srf
+SELECT generate_series(1, 3);
+ generate_series 
+-----------------
+               1
+               2
+               3
+(3 rows)
+
+-- parallel iteration
+SELECT generate_series(1, 3), generate_series(3,5);
+ generate_series | generate_series 
+-----------------+-----------------
+               1 |               3
+               2 |               4
+               3 |               5
+(3 rows)
+
+-- parallel iteration, different number of rows
+SELECT generate_series(1, 2), generate_series(1,4);
+ generate_series | generate_series 
+-----------------+-----------------
+               1 |               1
+               2 |               2
+               1 |               3
+               2 |               4
+(4 rows)
+
+-- srf, with SRF argument
+SELECT generate_series(1, generate_series(1, 3));
+ generate_series 
+-----------------
+               1
+               1
+               2
+               1
+               2
+               3
+(6 rows)
+
+-- srf, with two SRF arguments
+SELECT generate_series(generate_series(1,3), generate_series(2, 4));
+ERROR:  functions and operators can take at most one set argument
+CREATE TABLE few(id int, dataa text, datab text);
+INSERT INTO few VALUES(1, 'a', 'foo'),(2, 'a', 'bar'),(3, 'b', 'bar');
+-- SRF output order of sorting is maintained, if SRF is not referenced
+SELECT few.id, generate_series(1,3) g FROM few ORDER BY id DESC;
+ id | g 
+----+---
+  3 | 1
+  3 | 2
+  3 | 3
+  2 | 1
+  2 | 2
+  2 | 3
+  1 | 1
+  1 | 2
+  1 | 3
+(9 rows)
+
+-- but SRFs can be referenced in sort
+SELECT few.id, generate_series(1,3) g FROM few ORDER BY id, g DESC;
+ id | g 
+----+---
+  1 | 3
+  1 | 2
+  1 | 1
+  2 | 3
+  2 | 2
+  2 | 1
+  3 | 3
+  3 | 2
+  3 | 1
+(9 rows)
+
+SELECT few.id, generate_series(1,3) g FROM few ORDER BY id, generate_series(1,3) DESC;
+ id | g 
+----+---
+  1 | 3
+  1 | 2
+  1 | 1
+  2 | 3
+  2 | 2
+  2 | 1
+  3 | 3
+  3 | 2
+  3 | 1
+(9 rows)
+
+-- it's weird to have ORDER BYs that increase the number of results
+SELECT few.id FROM few ORDER BY id, generate_series(1,3) DESC;
+ id 
+----
+  1
+  1
+  1
+  2
+  2
+  2
+  3
+  3
+  3
+(9 rows)
+
+-- SRFs are computed after aggregation
+SELECT few.dataa, count(*), min(id), max(id), unnest('{1,1,3}'::int[]) FROM few WHERE few.id = 1 GROUP BY few.dataa;
+ dataa | count | min | max | unnest 
+-------+-------+-----+-----+--------
+ a     |     1 |   1 |   1 |      1
+ a     |     1 |   1 |   1 |      1
+ a     |     1 |   1 |   1 |      3
+(3 rows)
+
+-- unless referenced in GROUP BY clause
+SELECT few.dataa, count(*), min(id), max(id), unnest('{1,1,3}'::int[]) FROM few WHERE few.id = 1 GROUP BY few.dataa, unnest('{1,1,3}'::int[]);
+ dataa | count | min | max | unnest 
+-------+-------+-----+-----+--------
+ a     |     2 |   1 |   1 |      1
+ a     |     1 |   1 |   1 |      3
+(2 rows)
+
+SELECT few.dataa, count(*), min(id), max(id), unnest('{1,1,3}'::int[]) FROM few WHERE few.id = 1 GROUP BY few.dataa, 5;
+ dataa | count | min | max | unnest 
+-------+-------+-----+-----+--------
+ a     |     2 |   1 |   1 |      1
+ a     |     1 |   1 |   1 |      3
+(2 rows)
+
+-- check HAVING works when GROUP BY does [not] reference SRF output
+SELECT dataa, generate_series(1,3), count(*) FROM few GROUP BY 1 HAVING count(*) > 1;
+ dataa | generate_series | count 
+-------+-----------------+-------
+ a     |               1 |     2
+ a     |               2 |     2
+ a     |               3 |     2
+(3 rows)
+
+SELECT dataa, generate_series(1,3), count(*) FROM few GROUP BY 1, 2 HAVING count(*) > 1;
+ dataa | generate_series | count 
+-------+-----------------+-------
+ a     |               1 |     2
+ a     |               2 |     2
+ a     |               3 |     2
+(3 rows)
+
+-- it's weird to have GROUP BYs that increase the number of results
+SELECT few.dataa, count(*), min(id), max(id) FROM few GROUP BY few.dataa;
+ dataa | count | min | max 
+-------+-------+-----+-----
+ b     |     1 |   3 |   3
+ a     |     2 |   1 |   2
+(2 rows)
+
+SELECT few.dataa, count(*), min(id), max(id) FROM few GROUP BY few.dataa, unnest('{1,1,3}'::int[]);
+ dataa | count | min | max 
+-------+-------+-----+-----
+ b     |     2 |   3 |   3
+ a     |     4 |   1 |   2
+ b     |     1 |   3 |   3
+ a     |     2 |   1 |   2
+(4 rows)
+
+-- SRFs are not allowed in aggregate arguments
+SELECT min(generate_series(1, 3)) FROM few;
+ERROR:  set-valued function called in context that cannot accept a set
+-- SRFs are normally computed after window functions
+SELECT id,lag(id) OVER(), count(*) OVER(), generate_series(1,3) FROM few;
+ id | lag | count | generate_series 
+----+-----+-------+-----------------
+  1 |     |     3 |               1
+  1 |     |     3 |               2
+  1 |     |     3 |               3
+  2 |   1 |     3 |               1
+  2 |   1 |     3 |               2
+  2 |   1 |     3 |               3
+  3 |   2 |     3 |               1
+  3 |   2 |     3 |               2
+  3 |   2 |     3 |               3
+(9 rows)
+
+-- unless referencing SRFs
+SELECT SUM(count(*)) OVER(PARTITION BY generate_series(1,3) ORDER BY generate_series(1,3)), generate_series(1,3) g FROM few GROUP BY g;
+ sum | g 
+-----+---
+   3 | 1
+   3 | 2
+   3 | 3
+(3 rows)
+
+-- sorting + grouping
+SELECT few.dataa, count(*), min(id), max(id), generate_series(1,3) FROM few GROUP BY few.dataa ORDER BY 5;
+ dataa | count | min | max | generate_series 
+-------+-------+-----+-----+-----------------
+ b     |     1 |   3 |   3 |               1
+ a     |     2 |   1 |   2 |               1
+ b     |     1 |   3 |   3 |               2
+ a     |     2 |   1 |   2 |               2
+ b     |     1 |   3 |   3 |               3
+ a     |     2 |   1 |   2 |               3
+(6 rows)
+
+-- grouping sets are a bit special, they produce NULLs in columns not actually NULL
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab);
+ dataa |  b  | g | count 
+-------+-----+---+-------
+ a     | bar | 1 |     1
+ a     | bar | 2 |     1
+ a     | foo | 1 |     1
+ a     | foo | 2 |     1
+ a     |     | 1 |     2
+ a     |     | 2 |     2
+ b     | bar | 1 |     1
+ b     | bar | 2 |     1
+ b     |     | 1 |     1
+ b     |     | 2 |     1
+       |     | 1 |     3
+       |     | 2 |     3
+       | bar | 1 |     2
+       | bar | 2 |     2
+       | foo | 1 |     1
+       | foo | 2 |     1
+(16 rows)
+
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab) ORDER BY dataa;
+ dataa |  b  | g | count 
+-------+-----+---+-------
+ a     | bar | 1 |     1
+ a     | bar | 2 |     1
+ a     | foo | 1 |     1
+ a     | foo | 2 |     1
+ a     |     | 1 |     2
+ a     |     | 2 |     2
+ b     | bar | 1 |     1
+ b     | bar | 2 |     1
+ b     |     | 1 |     1
+ b     |     | 2 |     1
+       |     | 1 |     3
+       |     | 2 |     3
+       | bar | 1 |     2
+       | bar | 2 |     2
+       | foo | 1 |     1
+       | foo | 2 |     1
+(16 rows)
+
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab) ORDER BY g;
+ dataa |  b  | g | count 
+-------+-----+---+-------
+ a     | bar | 1 |     1
+ a     | foo | 1 |     1
+ a     |     | 1 |     2
+ b     | bar | 1 |     1
+ b     |     | 1 |     1
+       |     | 1 |     3
+       | bar | 1 |     2
+       | foo | 1 |     1
+       | foo | 2 |     1
+ a     | bar | 2 |     1
+ b     |     | 2 |     1
+ a     | foo | 2 |     1
+       | bar | 2 |     2
+ a     |     | 2 |     2
+       |     | 2 |     3
+ b     | bar | 2 |     1
+(16 rows)
+
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g);
+ dataa |  b  | g | count 
+-------+-----+---+-------
+ a     | bar | 1 |     1
+ a     | bar | 2 |     1
+ a     | bar |   |     2
+ a     | foo | 1 |     1
+ a     | foo | 2 |     1
+ a     | foo |   |     2
+ a     |     |   |     4
+ b     | bar | 1 |     1
+ b     | bar | 2 |     1
+ b     | bar |   |     2
+ b     |     |   |     2
+       |     |   |     6
+ a     |     | 1 |     2
+ b     |     | 1 |     1
+       |     | 1 |     3
+ a     |     | 2 |     2
+ b     |     | 2 |     1
+       |     | 2 |     3
+       | bar | 1 |     2
+       | bar | 2 |     2
+       | bar |   |     4
+       | foo | 1 |     1
+       | foo | 2 |     1
+       | foo |   |     2
+(24 rows)
+
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY dataa;
+ dataa |  b  | g | count 
+-------+-----+---+-------
+ a     | bar | 1 |     1
+ a     | bar | 2 |     1
+ a     | bar |   |     2
+ a     | foo | 1 |     1
+ a     | foo | 2 |     1
+ a     | foo |   |     2
+ a     |     |   |     4
+ a     |     | 1 |     2
+ a     |     | 2 |     2
+ b     | bar | 2 |     1
+ b     |     |   |     2
+ b     |     | 1 |     1
+ b     |     | 2 |     1
+ b     | bar | 1 |     1
+ b     | bar |   |     2
+       | foo |   |     2
+       | foo | 1 |     1
+       |     | 2 |     3
+       | bar | 1 |     2
+       | bar | 2 |     2
+       |     |   |     6
+       | foo | 2 |     1
+       | bar |   |     4
+       |     | 1 |     3
+(24 rows)
+
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY g;
+ dataa |  b  | g | count 
+-------+-----+---+-------
+ a     | bar | 1 |     1
+ a     | foo | 1 |     1
+ b     | bar | 1 |     1
+ a     |     | 1 |     2
+ b     |     | 1 |     1
+       |     | 1 |     3
+       | bar | 1 |     2
+       | foo | 1 |     1
+       | foo | 2 |     1
+       | bar | 2 |     2
+ a     |     | 2 |     2
+ b     |     | 2 |     1
+ a     | bar | 2 |     1
+       |     | 2 |     3
+ a     | foo | 2 |     1
+ b     | bar | 2 |     1
+ a     | foo |   |     2
+ b     | bar |   |     2
+ b     |     |   |     2
+       |     |   |     6
+ a     |     |   |     4
+       | bar |   |     4
+       | foo |   |     2
+ a     | bar |   |     2
+(24 rows)
+
+-- data modification
+CREATE TABLE fewmore AS SELECT generate_series(1,3) AS data;
+INSERT INTO fewmore VALUES(generate_series(4,5));
+SELECT * FROM fewmore;
+ data 
+------
+    1
+    2
+    3
+    4
+    5
+(5 rows)
+
+-- nonsense that seems to be allowed
+UPDATE fewmore SET data = generate_series(4,9);
+-- SRFs are not allowed in RETURNING
+INSERT INTO fewmore VALUES(1) RETURNING generate_series(1,3);
+ERROR:  set-valued function called in context that cannot accept a set
+-- nor aggregate arguments
+SELECT count(generate_series(1,3)) FROM few;
+ERROR:  set-valued function called in context that cannot accept a set
+-- nor proper VALUES
+VALUES(1, generate_series(1,2));
+ERROR:  set-valued function called in context that cannot accept a set
+-- DISTINCT ON is evaluated before tSRF evaluation if SRF is not
+-- referenced either in ORDER BY or in the DISTINCT ON list. The ORDER
+-- BY reference can be implicitly generated, if there's no other ORDER BY.
+-- implicit reference (via implicit ORDER) to all columns
+SELECT DISTINCT ON (a) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b);
+ a | b | g 
+---+---+---
+ 1 | 1 | 1
+ 3 | 2 | 1
+ 5 | 3 | 1
+(3 rows)
+
+-- unreferenced in DISTINCT ON or ORDER BY
+SELECT DISTINCT ON (a) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b)
+ORDER BY a, b DESC;
+ a | b | g 
+---+---+---
+ 1 | 4 | 1
+ 1 | 4 | 2
+ 1 | 4 | 3
+ 3 | 2 | 1
+ 3 | 2 | 2
+ 3 | 2 | 3
+ 5 | 3 | 1
+ 5 | 3 | 2
+ 5 | 3 | 3
+(9 rows)
+
+-- referenced in ORDER BY
+SELECT DISTINCT ON (a) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b)
+ORDER BY a, b DESC, g DESC;
+ a | b | g 
+---+---+---
+ 1 | 4 | 3
+ 3 | 2 | 3
+ 5 | 3 | 3
+(3 rows)
+
+-- referenced in ORDER BY and DISTINCT ON
+SELECT DISTINCT ON (a, b, g) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b)
+ORDER BY a, b DESC, g DESC;
+ a | b | g 
+---+---+---
+ 1 | 4 | 3
+ 1 | 4 | 2
+ 1 | 4 | 1
+ 1 | 1 | 3
+ 1 | 1 | 2
+ 1 | 1 | 1
+ 3 | 2 | 3
+ 3 | 2 | 2
+ 3 | 2 | 1
+ 3 | 1 | 3
+ 3 | 1 | 2
+ 3 | 1 | 1
+ 5 | 3 | 3
+ 5 | 3 | 2
+ 5 | 3 | 1
+ 5 | 1 | 3
+ 5 | 1 | 2
+ 5 | 1 | 1
+(18 rows)
+
+-- only SRF mentioned in DISTINCT ON
+SELECT DISTINCT ON (g) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b);
+ a | b | g 
+---+---+---
+ 3 | 2 | 1
+ 5 | 1 | 2
+ 3 | 1 | 3
+(3 rows)
+
+-- LIMIT / OFFSET is evaluated after SRF evaluation
+SELECT a, generate_series(1,2) FROM (VALUES(1),(2),(3)) r(a) LIMIT 2 OFFSET 2;
+ a | generate_series 
+---+-----------------
+ 2 |               1
+ 2 |               2
+(2 rows)
+
+-- SRFs are not allowed in LIMIT.
+SELECT 1 LIMIT generate_series(1,3);
+ERROR:  argument of LIMIT must not return a set
+LINE 1: SELECT 1 LIMIT generate_series(1,3);
+                       ^
+-- tSRF in correlated subquery, referencing table outside
+SELECT (SELECT generate_series(1,3) LIMIT 1 OFFSET few.id) FROM few;
+ generate_series 
+-----------------
+               2
+               3
+                
+(3 rows)
+
+-- tSRF in correlated subquery, referencing SRF outside
+SELECT (SELECT generate_series(1,3) LIMIT 1 OFFSET g.i) FROM generate_series(0,3) g(i);
+ generate_series 
+-----------------
+               1
+               2
+               3
+                
+(4 rows)
+
+-- Operators can return sets too
+CREATE OPERATOR |@| (PROCEDURE = unnest, RIGHTARG = ANYARRAY);
+SELECT |@|ARRAY[1,2,3];
+ ?column? 
+----------
+        1
+        2
+        3
+(3 rows)
+
+-- Clean up
+DROP TABLE few;
+DROP TABLE fewmore;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 1cb5dfc336d36e28a7b828e86738eb56cd9fe0f6..8641769351adb851f48f115d6f0b5b465f0d6daf 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -89,7 +89,7 @@ test: brin gin gist spgist privileges init_privs security_label collate matview
 # ----------
 # Another group of parallel tests
 # ----------
-test: alter_generic alter_operator misc psql async dbsize misc_functions
+test: alter_generic alter_operator misc psql async dbsize misc_functions tsrf
 
 # rules cannot run concurrently with any test that creates a view
 test: rules psql_crosstab amutils
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 8958d8cdb9d29a46f6bc21a6b0069390794c41e1..835cf3556cc91a64fe6ab831f2895466e01b0ba7 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -123,6 +123,7 @@ test: psql
 test: async
 test: dbsize
 test: misc_functions
+test: tsrf
 test: rules
 test: psql_crosstab
 test: select_parallel
diff --git a/src/test/regress/sql/tsrf.sql b/src/test/regress/sql/tsrf.sql
new file mode 100644
index 0000000000000000000000000000000000000000..633dfd64c9ed19da6b804f04730bb73b127bd55f
--- /dev/null
+++ b/src/test/regress/sql/tsrf.sql
@@ -0,0 +1,124 @@
+--
+-- tsrf - targetlist set returning function tests
+--
+
+-- simple srf
+SELECT generate_series(1, 3);
+
+-- parallel iteration
+SELECT generate_series(1, 3), generate_series(3,5);
+
+-- parallel iteration, different number of rows
+SELECT generate_series(1, 2), generate_series(1,4);
+
+-- srf, with SRF argument
+SELECT generate_series(1, generate_series(1, 3));
+
+-- srf, with two SRF arguments
+SELECT generate_series(generate_series(1,3), generate_series(2, 4));
+
+CREATE TABLE few(id int, dataa text, datab text);
+INSERT INTO few VALUES(1, 'a', 'foo'),(2, 'a', 'bar'),(3, 'b', 'bar');
+
+-- SRF output order of sorting is maintained, if SRF is not referenced
+SELECT few.id, generate_series(1,3) g FROM few ORDER BY id DESC;
+
+-- but SRFs can be referenced in sort
+SELECT few.id, generate_series(1,3) g FROM few ORDER BY id, g DESC;
+SELECT few.id, generate_series(1,3) g FROM few ORDER BY id, generate_series(1,3) DESC;
+
+-- it's weird to have ORDER BYs that increase the number of results
+SELECT few.id FROM few ORDER BY id, generate_series(1,3) DESC;
+
+-- SRFs are computed after aggregation
+SELECT few.dataa, count(*), min(id), max(id), unnest('{1,1,3}'::int[]) FROM few WHERE few.id = 1 GROUP BY few.dataa;
+-- unless referenced in GROUP BY clause
+SELECT few.dataa, count(*), min(id), max(id), unnest('{1,1,3}'::int[]) FROM few WHERE few.id = 1 GROUP BY few.dataa, unnest('{1,1,3}'::int[]);
+SELECT few.dataa, count(*), min(id), max(id), unnest('{1,1,3}'::int[]) FROM few WHERE few.id = 1 GROUP BY few.dataa, 5;
+
+-- check HAVING works when GROUP BY does [not] reference SRF output
+SELECT dataa, generate_series(1,3), count(*) FROM few GROUP BY 1 HAVING count(*) > 1;
+SELECT dataa, generate_series(1,3), count(*) FROM few GROUP BY 1, 2 HAVING count(*) > 1;
+
+-- it's weird to have GROUP BYs that increase the number of results
+SELECT few.dataa, count(*), min(id), max(id) FROM few GROUP BY few.dataa;
+SELECT few.dataa, count(*), min(id), max(id) FROM few GROUP BY few.dataa, unnest('{1,1,3}'::int[]);
+
+-- SRFs are not allowed in aggregate arguments
+SELECT min(generate_series(1, 3)) FROM few;
+
+-- SRFs are normally computed after window functions
+SELECT id,lag(id) OVER(), count(*) OVER(), generate_series(1,3) FROM few;
+-- unless referencing SRFs
+SELECT SUM(count(*)) OVER(PARTITION BY generate_series(1,3) ORDER BY generate_series(1,3)), generate_series(1,3) g FROM few GROUP BY g;
+
+-- sorting + grouping
+SELECT few.dataa, count(*), min(id), max(id), generate_series(1,3) FROM few GROUP BY few.dataa ORDER BY 5;
+
+-- grouping sets are a bit special, they produce NULLs in columns not actually NULL
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab);
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab) ORDER BY dataa;
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab) ORDER BY g;
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g);
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY dataa;
+SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY g;
+
+-- data modification
+CREATE TABLE fewmore AS SELECT generate_series(1,3) AS data;
+INSERT INTO fewmore VALUES(generate_series(4,5));
+SELECT * FROM fewmore;
+
+-- nonsense that seems to be allowed
+UPDATE fewmore SET data = generate_series(4,9);
+
+-- SRFs are not allowed in RETURNING
+INSERT INTO fewmore VALUES(1) RETURNING generate_series(1,3);
+-- nor aggregate arguments
+SELECT count(generate_series(1,3)) FROM few;
+-- nor proper VALUES
+VALUES(1, generate_series(1,2));
+
+-- DISTINCT ON is evaluated before tSRF evaluation if SRF is not
+-- referenced either in ORDER BY or in the DISTINCT ON list. The ORDER
+-- BY reference can be implicitly generated, if there's no other ORDER BY.
+
+-- implicit reference (via implicit ORDER) to all columns
+SELECT DISTINCT ON (a) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b);
+
+-- unreferenced in DISTINCT ON or ORDER BY
+SELECT DISTINCT ON (a) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b)
+ORDER BY a, b DESC;
+
+-- referenced in ORDER BY
+SELECT DISTINCT ON (a) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b)
+ORDER BY a, b DESC, g DESC;
+
+-- referenced in ORDER BY and DISTINCT ON
+SELECT DISTINCT ON (a, b, g) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b)
+ORDER BY a, b DESC, g DESC;
+
+-- only SRF mentioned in DISTINCT ON
+SELECT DISTINCT ON (g) a, b, generate_series(1,3) g
+FROM (VALUES (3, 2), (3,1), (1,1), (1,4), (5,3), (5,1)) AS t(a, b);
+
+-- LIMIT / OFFSET is evaluated after SRF evaluation
+SELECT a, generate_series(1,2) FROM (VALUES(1),(2),(3)) r(a) LIMIT 2 OFFSET 2;
+-- SRFs are not allowed in LIMIT.
+SELECT 1 LIMIT generate_series(1,3);
+
+-- tSRF in correlated subquery, referencing table outside
+SELECT (SELECT generate_series(1,3) LIMIT 1 OFFSET few.id) FROM few;
+-- tSRF in correlated subquery, referencing SRF outside
+SELECT (SELECT generate_series(1,3) LIMIT 1 OFFSET g.i) FROM generate_series(0,3) g(i);
+
+-- Operators can return sets too
+CREATE OPERATOR |@| (PROCEDURE = unnest, RIGHTARG = ANYARRAY);
+SELECT |@|ARRAY[1,2,3];
+
+-- Clean up
+DROP TABLE few;
+DROP TABLE fewmore;