mirror of https://github.com/postgres/postgres
other columns to be referenced without listing them in GROUP BY, so long as the primary key column(s) are listed in GROUP BY. Eventually we should also allow functional dependency on a UNIQUE constraint when the columns are marked NOT NULL, but that has to wait until NOT NULL constraints are represented in pg_constraint, because we need to have pg_constraint OIDs for all the conditions needed to ensure functional dependency. Peter Eisentraut, reviewed by Alex Hunsaker and Tom Lanepull/1/head
parent
ce6ce1a09d
commit
e49ae8d3bc
@ -0,0 +1,241 @@ |
||||
-- from http://www.depesz.com/index.php/2010/04/19/getting-unique-elements/ |
||||
CREATE TEMP TABLE articles ( |
||||
id int CONSTRAINT articles_pkey PRIMARY KEY, |
||||
keywords text, |
||||
title text UNIQUE NOT NULL, |
||||
body text UNIQUE, |
||||
created date |
||||
); |
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "articles_pkey" for table "articles" |
||||
NOTICE: CREATE TABLE / UNIQUE will create implicit index "articles_title_key" for table "articles" |
||||
NOTICE: CREATE TABLE / UNIQUE will create implicit index "articles_body_key" for table "articles" |
||||
CREATE TEMP TABLE articles_in_category ( |
||||
article_id int, |
||||
category_id int, |
||||
changed date, |
||||
PRIMARY KEY (article_id, category_id) |
||||
); |
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "articles_in_category_pkey" for table "articles_in_category" |
||||
-- test functional dependencies based on primary keys/unique constraints |
||||
-- base tables |
||||
-- group by primary key (OK) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
id | keywords | title | body | created |
||||
----+----------+-------+------+--------- |
||||
(0 rows) |
||||
|
||||
-- group by unique not null (fail/todo) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY title; |
||||
ERROR: column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT id, keywords, title, body, created |
||||
^ |
||||
-- group by unique nullable (fail) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY body; |
||||
ERROR: column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT id, keywords, title, body, created |
||||
^ |
||||
-- group by something else (fail) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY keywords; |
||||
ERROR: column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT id, keywords, title, body, created |
||||
^ |
||||
-- multiple tables |
||||
-- group by primary key (OK) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a, articles_in_category AS aic |
||||
WHERE a.id = aic.article_id AND aic.category_id in (14,62,70,53,138) |
||||
GROUP BY a.id; |
||||
id | keywords | title | body | created |
||||
----+----------+-------+------+--------- |
||||
(0 rows) |
||||
|
||||
-- group by something else (fail) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a, articles_in_category AS aic |
||||
WHERE a.id = aic.article_id AND aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.article_id, aic.category_id; |
||||
ERROR: column "a.id" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
^ |
||||
-- JOIN syntax |
||||
-- group by left table's primary key (OK) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY a.id; |
||||
id | keywords | title | body | created |
||||
----+----------+-------+------+--------- |
||||
(0 rows) |
||||
|
||||
-- group by something else (fail) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.article_id, aic.category_id; |
||||
ERROR: column "a.id" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
^ |
||||
-- group by right table's (composite) primary key (OK) |
||||
SELECT aic.changed |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.category_id, aic.article_id; |
||||
changed |
||||
--------- |
||||
(0 rows) |
||||
|
||||
-- group by right table's partial primary key (fail) |
||||
SELECT aic.changed |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.article_id; |
||||
ERROR: column "aic.changed" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT aic.changed |
||||
^ |
||||
-- example from documentation |
||||
CREATE TEMP TABLE products (product_id int, name text, price numeric); |
||||
CREATE TEMP TABLE sales (product_id int, units int); |
||||
-- OK |
||||
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
FROM products p LEFT JOIN sales s USING (product_id) |
||||
GROUP BY product_id, p.name, p.price; |
||||
product_id | name | sales |
||||
------------+------+------- |
||||
(0 rows) |
||||
|
||||
-- fail |
||||
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
FROM products p LEFT JOIN sales s USING (product_id) |
||||
GROUP BY product_id; |
||||
ERROR: column "p.name" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 1: SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
^ |
||||
ALTER TABLE products ADD PRIMARY KEY (product_id); |
||||
NOTICE: ALTER TABLE / ADD PRIMARY KEY will create implicit index "products_pkey" for table "products" |
||||
-- OK now |
||||
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
FROM products p LEFT JOIN sales s USING (product_id) |
||||
GROUP BY product_id; |
||||
product_id | name | sales |
||||
------------+------+------- |
||||
(0 rows) |
||||
|
||||
-- Drupal example, http://drupal.org/node/555530 |
||||
CREATE TEMP TABLE node ( |
||||
nid SERIAL, |
||||
vid integer NOT NULL default '0', |
||||
type varchar(32) NOT NULL default '', |
||||
title varchar(128) NOT NULL default '', |
||||
uid integer NOT NULL default '0', |
||||
status integer NOT NULL default '1', |
||||
created integer NOT NULL default '0', |
||||
-- snip |
||||
PRIMARY KEY (nid, vid) |
||||
); |
||||
NOTICE: CREATE TABLE will create implicit sequence "node_nid_seq" for serial column "node.nid" |
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "node_pkey" for table "node" |
||||
CREATE TEMP TABLE users ( |
||||
uid integer NOT NULL default '0', |
||||
name varchar(60) NOT NULL default '', |
||||
pass varchar(32) NOT NULL default '', |
||||
-- snip |
||||
PRIMARY KEY (uid), |
||||
UNIQUE (name) |
||||
); |
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "users_pkey" for table "users" |
||||
NOTICE: CREATE TABLE / UNIQUE will create implicit index "users_name_key" for table "users" |
||||
-- OK |
||||
SELECT u.uid, u.name FROM node n |
||||
INNER JOIN users u ON u.uid = n.uid |
||||
WHERE n.type = 'blog' AND n.status = 1 |
||||
GROUP BY u.uid, u.name; |
||||
uid | name |
||||
-----+------ |
||||
(0 rows) |
||||
|
||||
-- OK |
||||
SELECT u.uid, u.name FROM node n |
||||
INNER JOIN users u ON u.uid = n.uid |
||||
WHERE n.type = 'blog' AND n.status = 1 |
||||
GROUP BY u.uid; |
||||
uid | name |
||||
-----+------ |
||||
(0 rows) |
||||
|
||||
-- Check views and dependencies |
||||
-- fail |
||||
CREATE TEMP VIEW fdv1 AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY body; |
||||
ERROR: column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function |
||||
LINE 2: SELECT id, keywords, title, body, created |
||||
^ |
||||
-- OK |
||||
CREATE TEMP VIEW fdv1 AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
-- fail |
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; |
||||
ERROR: cannot drop constraint articles_pkey on table articles because other objects depend on it |
||||
DETAIL: view fdv1 depends on constraint articles_pkey on table articles |
||||
HINT: Use DROP ... CASCADE to drop the dependent objects too. |
||||
DROP VIEW fdv1; |
||||
-- multiple dependencies |
||||
CREATE TEMP VIEW fdv2 AS |
||||
SELECT a.id, a.keywords, a.title, aic.category_id, aic.changed |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY a.id, aic.category_id, aic.article_id; |
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail |
||||
ERROR: cannot drop constraint articles_pkey on table articles because other objects depend on it |
||||
DETAIL: view fdv2 depends on constraint articles_pkey on table articles |
||||
HINT: Use DROP ... CASCADE to drop the dependent objects too. |
||||
ALTER TABLE articles_in_category DROP CONSTRAINT articles_in_category_pkey RESTRICT; --fail |
||||
ERROR: cannot drop constraint articles_in_category_pkey on table articles_in_category because other objects depend on it |
||||
DETAIL: view fdv2 depends on constraint articles_in_category_pkey on table articles_in_category |
||||
HINT: Use DROP ... CASCADE to drop the dependent objects too. |
||||
DROP VIEW fdv2; |
||||
-- nested queries |
||||
CREATE TEMP VIEW fdv3 AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id |
||||
UNION |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail |
||||
ERROR: cannot drop constraint articles_pkey on table articles because other objects depend on it |
||||
DETAIL: view fdv3 depends on constraint articles_pkey on table articles |
||||
HINT: Use DROP ... CASCADE to drop the dependent objects too. |
||||
DROP VIEW fdv3; |
||||
CREATE TEMP VIEW fdv4 AS |
||||
SELECT * FROM articles WHERE title IN (SELECT title FROM articles GROUP BY id); |
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail |
||||
ERROR: cannot drop constraint articles_pkey on table articles because other objects depend on it |
||||
DETAIL: view fdv4 depends on constraint articles_pkey on table articles |
||||
HINT: Use DROP ... CASCADE to drop the dependent objects too. |
||||
DROP VIEW fdv4; |
||||
-- prepared query plans: this results in failure on reuse |
||||
PREPARE foo AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
EXECUTE foo; |
||||
id | keywords | title | body | created |
||||
----+----------+-------+------+--------- |
||||
(0 rows) |
||||
|
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; |
||||
EXECUTE foo; -- fail |
||||
ERROR: column "articles.keywords" must appear in the GROUP BY clause or be used in an aggregate function |
@ -0,0 +1,210 @@ |
||||
-- from http://www.depesz.com/index.php/2010/04/19/getting-unique-elements/ |
||||
|
||||
CREATE TEMP TABLE articles ( |
||||
id int CONSTRAINT articles_pkey PRIMARY KEY, |
||||
keywords text, |
||||
title text UNIQUE NOT NULL, |
||||
body text UNIQUE, |
||||
created date |
||||
); |
||||
|
||||
CREATE TEMP TABLE articles_in_category ( |
||||
article_id int, |
||||
category_id int, |
||||
changed date, |
||||
PRIMARY KEY (article_id, category_id) |
||||
); |
||||
|
||||
-- test functional dependencies based on primary keys/unique constraints |
||||
|
||||
-- base tables |
||||
|
||||
-- group by primary key (OK) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
|
||||
-- group by unique not null (fail/todo) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY title; |
||||
|
||||
-- group by unique nullable (fail) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY body; |
||||
|
||||
-- group by something else (fail) |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY keywords; |
||||
|
||||
-- multiple tables |
||||
|
||||
-- group by primary key (OK) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a, articles_in_category AS aic |
||||
WHERE a.id = aic.article_id AND aic.category_id in (14,62,70,53,138) |
||||
GROUP BY a.id; |
||||
|
||||
-- group by something else (fail) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a, articles_in_category AS aic |
||||
WHERE a.id = aic.article_id AND aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.article_id, aic.category_id; |
||||
|
||||
-- JOIN syntax |
||||
|
||||
-- group by left table's primary key (OK) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY a.id; |
||||
|
||||
-- group by something else (fail) |
||||
SELECT a.id, a.keywords, a.title, a.body, a.created |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.article_id, aic.category_id; |
||||
|
||||
-- group by right table's (composite) primary key (OK) |
||||
SELECT aic.changed |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.category_id, aic.article_id; |
||||
|
||||
-- group by right table's partial primary key (fail) |
||||
SELECT aic.changed |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY aic.article_id; |
||||
|
||||
|
||||
-- example from documentation |
||||
|
||||
CREATE TEMP TABLE products (product_id int, name text, price numeric); |
||||
CREATE TEMP TABLE sales (product_id int, units int); |
||||
|
||||
-- OK |
||||
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
FROM products p LEFT JOIN sales s USING (product_id) |
||||
GROUP BY product_id, p.name, p.price; |
||||
|
||||
-- fail |
||||
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
FROM products p LEFT JOIN sales s USING (product_id) |
||||
GROUP BY product_id; |
||||
|
||||
ALTER TABLE products ADD PRIMARY KEY (product_id); |
||||
|
||||
-- OK now |
||||
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
||||
FROM products p LEFT JOIN sales s USING (product_id) |
||||
GROUP BY product_id; |
||||
|
||||
|
||||
-- Drupal example, http://drupal.org/node/555530 |
||||
|
||||
CREATE TEMP TABLE node ( |
||||
nid SERIAL, |
||||
vid integer NOT NULL default '0', |
||||
type varchar(32) NOT NULL default '', |
||||
title varchar(128) NOT NULL default '', |
||||
uid integer NOT NULL default '0', |
||||
status integer NOT NULL default '1', |
||||
created integer NOT NULL default '0', |
||||
-- snip |
||||
PRIMARY KEY (nid, vid) |
||||
); |
||||
|
||||
CREATE TEMP TABLE users ( |
||||
uid integer NOT NULL default '0', |
||||
name varchar(60) NOT NULL default '', |
||||
pass varchar(32) NOT NULL default '', |
||||
-- snip |
||||
PRIMARY KEY (uid), |
||||
UNIQUE (name) |
||||
); |
||||
|
||||
-- OK |
||||
SELECT u.uid, u.name FROM node n |
||||
INNER JOIN users u ON u.uid = n.uid |
||||
WHERE n.type = 'blog' AND n.status = 1 |
||||
GROUP BY u.uid, u.name; |
||||
|
||||
-- OK |
||||
SELECT u.uid, u.name FROM node n |
||||
INNER JOIN users u ON u.uid = n.uid |
||||
WHERE n.type = 'blog' AND n.status = 1 |
||||
GROUP BY u.uid; |
||||
|
||||
|
||||
-- Check views and dependencies |
||||
|
||||
-- fail |
||||
CREATE TEMP VIEW fdv1 AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY body; |
||||
|
||||
-- OK |
||||
CREATE TEMP VIEW fdv1 AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
|
||||
-- fail |
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; |
||||
|
||||
DROP VIEW fdv1; |
||||
|
||||
|
||||
-- multiple dependencies |
||||
CREATE TEMP VIEW fdv2 AS |
||||
SELECT a.id, a.keywords, a.title, aic.category_id, aic.changed |
||||
FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id |
||||
WHERE aic.category_id in (14,62,70,53,138) |
||||
GROUP BY a.id, aic.category_id, aic.article_id; |
||||
|
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail |
||||
ALTER TABLE articles_in_category DROP CONSTRAINT articles_in_category_pkey RESTRICT; --fail |
||||
|
||||
DROP VIEW fdv2; |
||||
|
||||
|
||||
-- nested queries |
||||
|
||||
CREATE TEMP VIEW fdv3 AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id |
||||
UNION |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
|
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail |
||||
|
||||
DROP VIEW fdv3; |
||||
|
||||
|
||||
CREATE TEMP VIEW fdv4 AS |
||||
SELECT * FROM articles WHERE title IN (SELECT title FROM articles GROUP BY id); |
||||
|
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail |
||||
|
||||
DROP VIEW fdv4; |
||||
|
||||
|
||||
-- prepared query plans: this results in failure on reuse |
||||
|
||||
PREPARE foo AS |
||||
SELECT id, keywords, title, body, created |
||||
FROM articles |
||||
GROUP BY id; |
||||
|
||||
EXECUTE foo; |
||||
|
||||
ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; |
||||
|
||||
EXECUTE foo; -- fail |
Loading…
Reference in new issue