Re: count(boolean)

From: "Joel Burton" <joel(at)joelburton(dot)com>
To: "Dan MacNeil" <dan(at)ltc(dot)org>, "pgsql-sql" <pgsql-sql(at)postgresql(dot)org>
Subject: Re: count(boolean)
Date: 2002-05-19 14:58:16
Message-ID: JGEPJNMCKODMDHGOBKDNMELMCOAA.joel@joelburton.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

SELECT question_id,
COUNT(*)
FROM Ansers_Boolean
WHERE value=TRUE
GROUP BY question_id;

sort of works; it's fast & correct, but if a question has no true responses,
it leaves off that question. This may or may not be acceptable to you.

You could fix that with:

SELECT question_id,
COUNT(*)
FROM Answers_Boolean
WHERE value=TRUE
GROUP BY question_id

UNION ALL

SELECT question_id,
0
FROM Answers_Boolean AS AB0
WHERE NOT EXISTS (SELECT *
FROM Answers_Boolean AS AB1
WHERE AB0.question_id = AB1.question_id
AND value = TRUE);

But it performs slowly. I normally create turn the bools into 1 or 0 and add
them up (called a "Characteristic function"):

SELECT question_id,
SUM(CASE value WHEN TRUE THEN 1 ELSE 0 END) AS num_true
FROM Answers_Boolean
GROUP BY question_id;

Plus, it's easy this way to add a num_false column, by just copying
num_true.

Joel BURTON | joel(at)joelburton(dot)com | joelburton.com | aim: wjoelburton
Knowledge Management & Technology Consultant

> -----Original Message-----
> From: pgsql-sql-owner(at)postgresql(dot)org
> [mailto:pgsql-sql-owner(at)postgresql(dot)org]On Behalf Of Dan MacNeil
> Sent: Sunday, May 19, 2002 10:17 AM
> To: pgsql-sql
> Subject: [SQL] count(boolean)
>
>
> I have a table answers_boolean:
>
> question_id | integer | not null
> evaluation_id | integer | not null
> value | boolean |
>
> I'd like output in the form:
>
> question_id, count_true, count_false
>
> ....where count_true is the number of questions answered "true"
>
> SELECT
> question_id AS id, value AS val , count(value) AS cnt
> FROM
> answers_boolean
> GROUP BY
> question_id,value;
>
> gives me:
> id | val | cnt
> ----+-----+-----
> 2 | f | 3
> 2 | t | 3
> 3 | f | 2
> 3 | t | 4
>
> ...which is sorta what I want.
>
> I've looked through the docs & archive but haven't found the answer.
>
> TIA
>
> ---------------------------(end of broadcast)---------------------------
> TIP 3: if posting/reading through Usenet, please send an appropriate
> subscribe-nomail command to majordomo(at)postgresql(dot)org so that your
> message can get through to the mailing list cleanly
>

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Josh Berkus 2002-05-19 20:36:10 A proposal for Interval Math
Previous Message Dan MacNeil 2002-05-19 14:16:47 count(boolean)