ClickHouse/docs/en/query_language/functions/functions_for_nulls.md
Ivan Blinkov 2e1f6bc56d
[experimental] add "es" docs language as machine translated draft (#9787)
* replace exit with assert in test_single_page

* improve save_raw_single_page docs option

* More grammar fixes

* "Built from" link in new tab

* fix mistype

* Example of include in docs

* add anchor to meeting form

* Draft of translation helper

* WIP on translation helper

* Replace some fa docs content with machine translation

* add normalize-en-markdown.sh

* normalize some en markdown

* normalize some en markdown

* admonition support

* normalize

* normalize

* normalize

* support wide tables

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* normalize

* lightly edited machine translation of introdpection.md

* lightly edited machhine translation of lazy.md

* WIP on translation utils

* Normalize ru docs

* Normalize other languages

* some fixes

* WIP on normalize/translate tools

* add requirements.txt

* [experimental] add es docs language as machine translated draft

* remove duplicate script

* Back to wider tab-stop (narrow renders not so well)
2020-03-21 07:11:51 +03:00

6.3 KiB

Functions for working with Nullable aggregates

isNull

Checks whether the argument is NULL.

isNull(x)

Parameters

  • x — A value with a non-compound data type.

Returned value

  • 1 if x is NULL.
  • 0 if x is not NULL.

Example

Input table

┌─x─┬────y─┐
│ 1 │ ᴺᵁᴸᴸ │
│ 2 │    3 │
└───┴──────┘

Query

SELECT x FROM t_null WHERE isNull(y)
┌─x─┐
│ 1 │
└───┘

isNotNull

Checks whether the argument is NULL.

isNotNull(x)

Parameters:

  • x — A value with a non-compound data type.

Returned value

  • 0 if x is NULL.
  • 1 if x is not NULL.

Example

Input table

┌─x─┬────y─┐
│ 1 │ ᴺᵁᴸᴸ │
│ 2 │    3 │
└───┴──────┘

Query

SELECT x FROM t_null WHERE isNotNull(y)
┌─x─┐
│ 2 │
└───┘

coalesce

Checks from left to right whether NULL arguments were passed and returns the first non-NULL argument.

coalesce(x,...)

Parameters:

  • Any number of parameters of a non-compound type. All parameters must be compatible by data type.

Returned values

  • The first non-NULL argument.
  • NULL, if all arguments are NULL.

Example

Consider a list of contacts that may specify multiple ways to contact a customer.

┌─name─────┬─mail─┬─phone─────┬──icq─┐
│ client 1 │ ᴺᵁᴸᴸ │ 123-45-67 │  123 │
│ client 2 │ ᴺᵁᴸᴸ │ ᴺᵁᴸᴸ      │ ᴺᵁᴸᴸ │
└──────────┴──────┴───────────┴──────┘

The mail and phone fields are of type String, but the icq field is UInt32, so it needs to be converted to String.

Get the first available contact method for the customer from the contact list:

SELECT coalesce(mail, phone, CAST(icq,'Nullable(String)')) FROM aBook
┌─name─────┬─coalesce(mail, phone, CAST(icq, 'Nullable(String)'))─┐
│ client 1 │ 123-45-67                                            │
│ client 2 │ ᴺᵁᴸᴸ                                                 │
└──────────┴──────────────────────────────────────────────────────┘

ifNull

Returns an alternative value if the main argument is NULL.

ifNull(x,alt)

Parameters:

  • x — The value to check for NULL.
  • alt — The value that the function returns if x is NULL.

Returned values

  • The value x, if x is not NULL.
  • The value alt, if x is NULL.

Example

SELECT ifNull('a', 'b')
┌─ifNull('a', 'b')─┐
│ a                │
└──────────────────┘
SELECT ifNull(NULL, 'b')
┌─ifNull(NULL, 'b')─┐
│ b                 │
└───────────────────┘

nullIf

Returns NULL if the arguments are equal.

nullIf(x, y)

Parameters:

x, y — Values for comparison. They must be compatible types, or ClickHouse will generate an exception.

Returned values

  • NULL, if the arguments are equal.
  • The x value, if the arguments are not equal.

Example

SELECT nullIf(1, 1)
┌─nullIf(1, 1)─┐
│         ᴺᵁᴸᴸ │
└──────────────┘
SELECT nullIf(1, 2)
┌─nullIf(1, 2)─┐
│            1 │
└──────────────┘

assumeNotNull

Results in a value of type Nullable for a non- Nullable, if the value is not NULL.

assumeNotNull(x)

Parameters:

  • x — The original value.

Returned values

  • The original value from the non-Nullable type, if it is not NULL.
  • The default value for the non-Nullable type if the original value was NULL.

Example

Consider the t_null table.

SHOW CREATE TABLE t_null
┌─statement─────────────────────────────────────────────────────────────────┐
│ CREATE TABLE default.t_null ( x Int8,  y Nullable(Int8)) ENGINE = TinyLog │
└───────────────────────────────────────────────────────────────────────────┘
┌─x─┬────y─┐
│ 1 │ ᴺᵁᴸᴸ │
│ 2 │    3 │
└───┴──────┘

Apply the assumeNotNull function to the y column.

SELECT assumeNotNull(y) FROM t_null
┌─assumeNotNull(y)─┐
│                0 │
│                3 │
└──────────────────┘
SELECT toTypeName(assumeNotNull(y)) FROM t_null
┌─toTypeName(assumeNotNull(y))─┐
│ Int8                         │
│ Int8                         │
└──────────────────────────────┘

toNullable

Converts the argument type to Nullable.

toNullable(x)

Parameters:

  • x — The value of any non-compound type.

Returned value

  • The input value with a Nullable type.

Example

SELECT toTypeName(10)
┌─toTypeName(10)─┐
│ UInt8          │
└────────────────┘
SELECT toTypeName(toNullable(10))
┌─toTypeName(toNullable(10))─┐
│ Nullable(UInt8)            │
└────────────────────────────┘

Original article