Re: Performant queries on table with many boolean columns

Поиск
Список
Период
Сортировка
От Merlin Moncure
Тема Re: Performant queries on table with many boolean columns
Дата
Msg-id CAHyXU0xJcfd0BhV1Ln3WTNAHZz1qa0AupqRYaOLcO3BaTD3Nag@mail.gmail.com
обсуждение исходный текст
Ответ на Re: Performant queries on table with many boolean columns  (bricklen <bricklen@gmail.com>)
Ответы Re: Performant queries on table with many boolean columns  (Adam Brusselback <adambrusselback@gmail.com>)
Список pgsql-performance
On Sun, Apr 24, 2016 at 3:14 PM, bricklen <bricklen@gmail.com> wrote:
> Query plan for the md5() index test:
>
>  Index Scan using lots_of_columns_md5_idx on lots_of_columns
> (cost=0.93..3.94 rows=1 width=208) (actual time=0.043..0.043 rows=1 loops=1)
>    Index Cond: ('1ba23a0668ec17e230d98c270d6664dc'::text =
> md5(((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((((c1)::text
> || (c2)::text) || (c3)::text) || (c4)::text) || (c5)::text) || (c6)::text)
> || (c7)::text) || (c8)::text) || (c9)::text) || (c10)::text) || (c11)::text)
> || (c12)::text) || (c13)::text) || (c14)::text) || (c15)::text) ||
> (c16)::text) || (c17)::text) || (c18)::text) || (c19)::text) || (c20)::text)
> || (c21)::text) || (c22)::text) || (c23)::text) || (c24)::text) ||
> (c25)::text) || (c26)::text) || (c27)::text) || (c28)::text) || (c29)::text)
> || (c30)::text) || (c31)::text) || (c32)::text) || (c33)::text) ||
> (c34)::text) || (c35)::text) || (c36)::text) || (c37)::text) || (c38)::text)
> || (c39)::text) || (c40)::text) || (c41)::text) || (c42)::text) ||
> (c43)::text) || (c44)::text) || (c45)::text) || (c46)::text) || (c47)::text)
> || (c48)::text) || (c49)::text) || (c50)::text) || (c51)::text) ||
> (c52)::text) || (c53)::text) || (c54)::text) || (c55)::text) || (c56)::text)
> || (c57)::text) || (c58)::text) || (c59)::text) || (c60)::text) ||
> (c61)::text) || (c62)::text) || (c63)::text) || (c64)::text) || (c65)::text)
> || (c66)::text) || (c67)::text) || (c68)::text) || (c69)::text) ||
> (c70)::text) || (c71)::text) || (c72)::text) || (c73)::text) || (c74)::text)
> || (c75)::text) || (c76)::text) || (c77)::text) || (c78)::text) ||
> (c79)::text) || (c80)::text) || (c81)::text) || (c82)::text) || (c83)::text)
> || (c84)::text) || (c85)::text) || (c86)::text) || (c87)::text) ||
> (c88)::text) || (c89)::text) || (c90)::text) || (c91)::text) || (c92)::text)
> || (c93)::text) || (c94)::text) || (c95)::text) || (c96)::text) ||
> (c97)::text) || (c98)::text) || (c99)::text) || (c100)::text)))
>    Buffers: shared hit=4
>  Planning time: 0.389 ms
>  Execution time: 0.129 ms
> (5 rows)

Hm.  Maybe use VARBIT? (assuming there are no null values or null can
be treated as false).

CREATE OR REPLACE FUNCTION MakeVarBit(VARIADIC BOOL[]) RETURNS VARBIT AS
$$
  SELECT string_agg(CASE WHEN v THEN '1' ELSE '0' END, '')::VARBIT
  FROM
  (
    SELECT UNNEST($1) v
  ) q;
$$ LANGUAGE SQL IMMUTABLE;

postgres=# select MakeVarBit(true, true, false);
 makevarbit
────────────
 110

create index on lots_of_columns (MakeVarBit(c1, c2, c3, c4 ...));

merlin


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

Предыдущее
От: Albe Laurenz
Дата:
Сообщение: Re: Performance problems with postgres and null Values?
Следующее
От: Adam Brusselback
Дата:
Сообщение: Re: Performant queries on table with many boolean columns