1-- from http://www.depesz.com/index.php/2010/04/19/getting-unique-elements/
2CREATE TEMP TABLE articles (
3    id int CONSTRAINT articles_pkey PRIMARY KEY,
4    keywords text,
5    title text UNIQUE NOT NULL,
6    body text UNIQUE,
7    created date
8);
9CREATE TEMP TABLE articles_in_category (
10    article_id int,
11    category_id int,
12    changed date,
13    PRIMARY KEY (article_id, category_id)
14);
15-- test functional dependencies based on primary keys/unique constraints
16-- base tables
17-- group by primary key (OK)
18SELECT id, keywords, title, body, created
19FROM articles
20GROUP BY id;
21 id | keywords | title | body | created
22----+----------+-------+------+---------
23(0 rows)
24
25-- group by unique not null (fail/todo)
26SELECT id, keywords, title, body, created
27FROM articles
28GROUP BY title;
29ERROR:  column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function
30LINE 1: SELECT id, keywords, title, body, created
31               ^
32-- group by unique nullable (fail)
33SELECT id, keywords, title, body, created
34FROM articles
35GROUP BY body;
36ERROR:  column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function
37LINE 1: SELECT id, keywords, title, body, created
38               ^
39-- group by something else (fail)
40SELECT id, keywords, title, body, created
41FROM articles
42GROUP BY keywords;
43ERROR:  column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function
44LINE 1: SELECT id, keywords, title, body, created
45               ^
46-- multiple tables
47-- group by primary key (OK)
48SELECT a.id, a.keywords, a.title, a.body, a.created
49FROM articles AS a, articles_in_category AS aic
50WHERE a.id = aic.article_id AND aic.category_id in (14,62,70,53,138)
51GROUP BY a.id;
52 id | keywords | title | body | created
53----+----------+-------+------+---------
54(0 rows)
55
56-- group by something else (fail)
57SELECT a.id, a.keywords, a.title, a.body, a.created
58FROM articles AS a, articles_in_category AS aic
59WHERE a.id = aic.article_id AND aic.category_id in (14,62,70,53,138)
60GROUP BY aic.article_id, aic.category_id;
61ERROR:  column "a.id" must appear in the GROUP BY clause or be used in an aggregate function
62LINE 1: SELECT a.id, a.keywords, a.title, a.body, a.created
63               ^
64-- JOIN syntax
65-- group by left table's primary key (OK)
66SELECT a.id, a.keywords, a.title, a.body, a.created
67FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id
68WHERE aic.category_id in (14,62,70,53,138)
69GROUP BY a.id;
70 id | keywords | title | body | created
71----+----------+-------+------+---------
72(0 rows)
73
74-- group by something else (fail)
75SELECT a.id, a.keywords, a.title, a.body, a.created
76FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id
77WHERE aic.category_id in (14,62,70,53,138)
78GROUP BY aic.article_id, aic.category_id;
79ERROR:  column "a.id" must appear in the GROUP BY clause or be used in an aggregate function
80LINE 1: SELECT a.id, a.keywords, a.title, a.body, a.created
81               ^
82-- group by right table's (composite) primary key (OK)
83SELECT aic.changed
84FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id
85WHERE aic.category_id in (14,62,70,53,138)
86GROUP BY aic.category_id, aic.article_id;
87 changed
88---------
89(0 rows)
90
91-- group by right table's partial primary key (fail)
92SELECT aic.changed
93FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id
94WHERE aic.category_id in (14,62,70,53,138)
95GROUP BY aic.article_id;
96ERROR:  column "aic.changed" must appear in the GROUP BY clause or be used in an aggregate function
97LINE 1: SELECT aic.changed
98               ^
99-- example from documentation
100CREATE TEMP TABLE products (product_id int, name text, price numeric);
101CREATE TEMP TABLE sales (product_id int, units int);
102-- OK
103SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
104    FROM products p LEFT JOIN sales s USING (product_id)
105    GROUP BY product_id, p.name, p.price;
106 product_id | name | sales
107------------+------+-------
108(0 rows)
109
110-- fail
111SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
112    FROM products p LEFT JOIN sales s USING (product_id)
113    GROUP BY product_id;
114ERROR:  column "p.name" must appear in the GROUP BY clause or be used in an aggregate function
115LINE 1: SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
116                           ^
117ALTER TABLE products ADD PRIMARY KEY (product_id);
118-- OK now
119SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
120    FROM products p LEFT JOIN sales s USING (product_id)
121    GROUP BY product_id;
122 product_id | name | sales
123------------+------+-------
124(0 rows)
125
126-- Drupal example, http://drupal.org/node/555530
127CREATE TEMP TABLE node (
128    nid SERIAL,
129    vid integer NOT NULL default '0',
130    type varchar(32) NOT NULL default '',
131    title varchar(128) NOT NULL default '',
132    uid integer NOT NULL default '0',
133    status integer NOT NULL default '1',
134    created integer NOT NULL default '0',
135    -- snip
136    PRIMARY KEY (nid, vid)
137);
138CREATE TEMP TABLE users (
139    uid integer NOT NULL default '0',
140    name varchar(60) NOT NULL default '',
141    pass varchar(32) NOT NULL default '',
142    -- snip
143    PRIMARY KEY (uid),
144    UNIQUE (name)
145);
146-- OK
147SELECT u.uid, u.name FROM node n
148INNER JOIN users u ON u.uid = n.uid
149WHERE n.type = 'blog' AND n.status = 1
150GROUP BY u.uid, u.name;
151 uid | name
152-----+------
153(0 rows)
154
155-- OK
156SELECT u.uid, u.name FROM node n
157INNER JOIN users u ON u.uid = n.uid
158WHERE n.type = 'blog' AND n.status = 1
159GROUP BY u.uid;
160 uid | name
161-----+------
162(0 rows)
163
164-- Check views and dependencies
165-- fail
166CREATE TEMP VIEW fdv1 AS
167SELECT id, keywords, title, body, created
168FROM articles
169GROUP BY body;
170ERROR:  column "articles.id" must appear in the GROUP BY clause or be used in an aggregate function
171LINE 2: SELECT id, keywords, title, body, created
172               ^
173-- OK
174CREATE TEMP VIEW fdv1 AS
175SELECT id, keywords, title, body, created
176FROM articles
177GROUP BY id;
178-- fail
179ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT;
180ERROR:  cannot drop constraint articles_pkey on table articles because other objects depend on it
181DETAIL:  view fdv1 depends on constraint articles_pkey on table articles
182HINT:  Use DROP ... CASCADE to drop the dependent objects too.
183DROP VIEW fdv1;
184-- multiple dependencies
185CREATE TEMP VIEW fdv2 AS
186SELECT a.id, a.keywords, a.title, aic.category_id, aic.changed
187FROM articles AS a JOIN articles_in_category AS aic ON a.id = aic.article_id
188WHERE aic.category_id in (14,62,70,53,138)
189GROUP BY a.id, aic.category_id, aic.article_id;
190ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail
191ERROR:  cannot drop constraint articles_pkey on table articles because other objects depend on it
192DETAIL:  view fdv2 depends on constraint articles_pkey on table articles
193HINT:  Use DROP ... CASCADE to drop the dependent objects too.
194ALTER TABLE articles_in_category DROP CONSTRAINT articles_in_category_pkey RESTRICT; --fail
195ERROR:  cannot drop constraint articles_in_category_pkey on table articles_in_category because other objects depend on it
196DETAIL:  view fdv2 depends on constraint articles_in_category_pkey on table articles_in_category
197HINT:  Use DROP ... CASCADE to drop the dependent objects too.
198DROP VIEW fdv2;
199-- nested queries
200CREATE TEMP VIEW fdv3 AS
201SELECT id, keywords, title, body, created
202FROM articles
203GROUP BY id
204UNION
205SELECT id, keywords, title, body, created
206FROM articles
207GROUP BY id;
208ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail
209ERROR:  cannot drop constraint articles_pkey on table articles because other objects depend on it
210DETAIL:  view fdv3 depends on constraint articles_pkey on table articles
211HINT:  Use DROP ... CASCADE to drop the dependent objects too.
212DROP VIEW fdv3;
213CREATE TEMP VIEW fdv4 AS
214SELECT * FROM articles WHERE title IN (SELECT title FROM articles GROUP BY id);
215ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT; -- fail
216ERROR:  cannot drop constraint articles_pkey on table articles because other objects depend on it
217DETAIL:  view fdv4 depends on constraint articles_pkey on table articles
218HINT:  Use DROP ... CASCADE to drop the dependent objects too.
219DROP VIEW fdv4;
220-- prepared query plans: this results in failure on reuse
221PREPARE foo AS
222  SELECT id, keywords, title, body, created
223  FROM articles
224  GROUP BY id;
225EXECUTE foo;
226 id | keywords | title | body | created
227----+----------+-------+------+---------
228(0 rows)
229
230ALTER TABLE articles DROP CONSTRAINT articles_pkey RESTRICT;
231EXECUTE foo;  -- fail
232ERROR:  column "articles.keywords" must appear in the GROUP BY clause or be used in an aggregate function
233