Re: count() counts ROW values that are NULL

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Erwin Brandstetter <brsaweda(at)gmail(dot)com>
Cc: pgsql-docs <pgsql-docs(at)postgresql(dot)org>
Subject: Re: count() counts ROW values that are NULL
Date: 2022-03-18 21:28:28
Message-ID: 1228519.1647638908@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-docs

Erwin Brandstetter <brsaweda(at)gmail(dot)com> writes:
> https://www.postgresql.org/docs/current/functions-aggregate.html#FUNCTIONS-AGGREGATE-TABLE
> The manual says:
>> count ( "any" ) → bigint
>> Computes the number of input rows in which the input value is not null.

> But ROW values or composite types that "are null" are counted, anyway.

Well, there's nulls and nulls. The SQL "IS NULL" construct is fairly
badly designed IMO, because it considers both a plain NULL and a
row-of-all-NULL-fields to be "null". count(), like just about everything
in Postgres other than "IS NULL", considers only a plain NULL to be null.

This is discussed somewhere in the manual, but I think it's under IS NULL,
not under all the other places that'd have to be annotated if we decide to
annotate as you're suggesting. (One example is that functions that are
marked STRICT use the tighter interpretation.)

You could use "COUNT(*) FILTER (WHERE NOT (whatever IS NULL))" if you want
to count values meeting the IS NULL definition. (Buttressing my point
that IS NULL is not well thought out, the obvious "whatever IS NOT NULL"
doesn't work here, because it's not the inverse of "whatever IS NULL".)

regards, tom lane

In response to

Responses

Browse pgsql-docs by date

  From Date Subject
Next Message Erwin Brandstetter 2022-03-18 22:05:33 Re: count() counts ROW values that are NULL
Previous Message Erwin Brandstetter 2022-03-18 20:58:15 count() counts ROW values that are NULL