Re: Selecting count of details along with details columns
От | Richard Huxton |
---|---|
Тема | Re: Selecting count of details along with details columns |
Дата | |
Msg-id | 433BBC07.5040208@archonet.com обсуждение исходный текст |
Ответ на | Re: Selecting count of details along with details columns (Axel Rau <Axel.Rau@Chaos1.DE>) |
Ответы |
Re: Selecting count of details along with details columns
|
Список | pgsql-sql |
Axel Rau wrote: > > Am 29.09.2005 um 10:30 schrieb Richard Huxton: > >> Axel Rau wrote: >> >>> SELECT T2.T2_name, COUNT(T1.id) AS xx >>> FROM T2, T1 >>> WHERE T2.id = T1.fk_t2 >>> GROUP BY T2.T2_name >>> HAVING COUNT(T1.id) > 1 >>> ORDER BY xx DESC; >>> t2_name | xx >>> ---------+---- >>> T2-N2 | 3 >>> T2-N3 | 2 >>> (2 rows) >>> Adding column t1_name to the result set breaks COUNT(T1.id): >>> SELECT T2.T2_name, T1.T1_name, COUNT(T1.id) AS xx >>> FROM T2, T1 >>> WHERE T2.id = T1.fk_t2 >>> GROUP BY T2.T2_name, T1.T1_name >>> HAVING COUNT(T1.id) > 1 >>> ORDER BY xx DESC; >>> t2_name | t1_name | xx >>> ---------+---------+---- >>> (0 rows) >>> How can I do this with pg ? >> >> >> Do what? You don't say what results you are expecting. >> >> Do you want: >> 1. ALL values of T1_name (in which case what count do you want)? >> 2. The FIRST value of T1_name (in which case what do you mean by first)? > > > #1.: > > t2_name | t1_name | count > ---------+---------+------- > T2-N2 | T1-CCC | 3 > T2-N3 | T1-FFF | 2 > T2-N2 | T1-BBB | 3 > T2-N2 | T1-DDD | 3 > T2-N3 | T1-EEE | 2 Ah - this is two questions: 1. What are the unique (t2_name,t1_name) pairings? 2. How many different (t1.id) values are there for each t2. So - something like: SELECT names.T2_name, names.T1_name, counts.num_t2 FROM ( SELECT DISTINCT T2.T2_name, T1.T1_name FROM T2,T1 WHERE T2.id = T1.fk_t2 ) AS names, ( SELECT T2.T2_name, COUNT(T1.id) AS num_t2 FROM T2, T1 WHERE T2.id = T1.fk_t2 GROUP BY T2.T2_name HAVING COUNT(T1.id) > 1 ) AS counts WHERE names.T2_name = counts.T2_name ; You could write the "names" sub-query with a GROUP BY if you wanted of course. -- Richard Huxton Archonet Ltd
В списке pgsql-sql по дате отправления: