Re: DISTINCT with NULLs and INT fields

Поиск
Список
Период
Сортировка
От Tom Lane
Тема Re: DISTINCT with NULLs and INT fields
Дата
Msg-id 21528.1135801169@sss.pgh.pa.us
обсуждение исходный текст
Ответ на DISTINCT with NULLs and INT fields  ("George Pavlov" <gpavlov@mynewplace.com>)
Список pgsql-sql
"George Pavlov" <gpavlov@mynewplace.com> writes:
> What does The SQL Standard say about this one?

> insert into foo (a, b) select distinct null, null from bar;
> -- ERROR:  column "b" is of type integer but expression is of type text

According to the SQL spec that query is illegal on its face --- the spec
does not allow a bare NULL keyword except in contexts where the datatype
is immediately evident.  You'd have had to writeSELECT DISTINCT CAST(NULL AS varchar), CAST(NULL AS int)
to be fully spec-conformant.

Postgres handles NULL the same way as untyped literals ('foo'), so we
tend to prefer resolving to type text when things are ambiguous.  In
this case the DISTINCT operation forces a type choice (if you don't know
what type the data is, you can hardly decide whether two values are equal
or not) and so by the time the INSERT sees it, it looks like a SELECT
of two text columns.

> Looks like SQL Server makes the NULLs be INTs, but is probably
> better at doing the implicit conversion from INT.

"Better" is in the eye of the beholder.  It surprises me not at all that
Microsoft would be lax about implicit coercions, but that doesn't make
it a good idea to coerce anything to anything else without complaint.
You might as well not have a type system at all, if you're going to
destroy its ability to detect mistakes that way.
        regards, tom lane


В списке pgsql-sql по дате отправления:

Предыдущее
От: "George Pavlov"
Дата:
Сообщение: DISTINCT with NULLs and INT fields
Следующее
От: "George Pavlov"
Дата:
Сообщение: Re: DISTINCT with NULLs and INT fields