where dt > ‘28-DEC-2023’ and dt < ‘28-DEC-2024’;
GIN Index :
GIN stands for Generalized Inverted Index, commonly referred to as GIN, are most useful when you have data types that contain
multiple values in a single column. GIN is designed for handling cases where the items to be indexed are composite values,
and the queries to be handled by the index need to search for element values that appear within the composite items.
The most common data types that fall into this bucket are:
hStore
Arrays
Range types
JSONB
tsvector :
Postgres has a data type called tsvector that is used for full text search. A tsvector value merges different variants of the
same word and removes duplicates to create a sorted list of distinct words called lexemes.
tsquery :
which supports indexed queries using these operators:
<@
@>
=
&&
Example:
db=# create table ts(doc text, doc_tsv tsvector);
CREATE TABLE
db=# insert into ts(doc) values
db-# ('Can a sheet slitter slit sheets?'),
db-# ('How many sheets could a sheet slitter slit?'),
db-# ('I slit a sheet, a sheet I slit.'),
db-# ('Upon a slitted sheet I sit.'),
db-# ('Whoever slit the sheets is a good sheet slitter.'),
db-# ('I am a sheet slitter.'),
db-# ('I slit sheets.'),
db-# ('I am the sleekest sheet slitter that ever slit sheets.'),
db-# ('She slits the sheet she sits on.');
INSERT 0 9
db=# update ts set doc_tsv = to_tsvector(doc);
UPDATE 9
db=# explain analyze select doc from ts where doc_tsv @@ to_tsquery('many & slitter');
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------
Seq Scan on ts (cost=10000000000.00..10000000241.00 rows=1 width=32) (actual time=0.104..0.161 rows=1 loops=1)
Filter: (doc_tsv @@ to_tsquery('many & slitter'::text))
Rows Removed by Filter: 8
Planning Time: 0.136 ms
Execution Time: 0.180 ms
(5 rows)
db=# create index on ts using gin(doc_tsv);
CREATE INDEX
db=# explain analyze select doc from ts where doc_tsv @@ to_tsquery('many & slitter');
QUERY PLAN -----------------------------------------------------------Bitmap Heap Scan on
ts (cost=12.25..16.51 rows=1 width=32) (actual time=0.066..0.067 rows=1 loops=1)
Recheck Cond: (doc_tsv @@ to_tsquery('many & slitter'::text))
Heap Blocks: exact=1
-> Bitmap Index Scan on ts_doc_tsv_idx (cost=0.00..12.25 rows=1 width=0) (actual time=0.057..0.057 rows=1 loops=1)
Index Cond: (doc_tsv @@ to_tsquery('many & slitter'::text))
Planning Time: 2.390 ms
Execution Time: 0.125 ms
(7 rows)
Gist Index : (postgresql - version 14)
GiST stands for Generalized Search Tree.
GiST indexes allow a building of general tree structures.
GiST indexes are useful in indexing geometric data types and full-text search.
Example:point,line,box,circle
which support indexed queries using these operators:
<<
&<
&>
>>
<<|
&<|
|&>
|>>
@>
<@
~=
&&
Example::
db=# create table points(p point);
CREATE TABLE
db=# insert into points(p) values
(point '(1,1)'), (point '(3,2)'), (point '(6,3)'),
(point '(5,5)'), (point '(7,8)'), (point '(8,6)');
INSERT 0 6
db=# explain analyze select * from points where p <@ box '(2,1),(7,4)';
QUERY PLAN
--------------------------------------------------------------------------------------------------
Seq Scan on points (cost=0.00..33.13 rows=2 width=16) (actual time=0.047..0.049 rows=2 loops=1)
Filter: (p <@ '(7,4),(2,1)'::box)
Rows Removed by Filter: 4
Planning Time: 1.621 ms
Execution Time: 0.082 ms
(5 rows)
db=# create index on points using gist(p);
CREATE INDEX
db=# explain analyze select * from points where p <@ box '(2,1),(7,4)';
QUERY PLAN
-------------------------------------------------------------------------------------------------
Seq Scan on points (cost=0.00..1.07 rows=1 width=16) (actual time=0.021..0.023 rows=2 loops=1)
Filter: (p <@ '(7,4),(2,1)'::box)
Rows Removed by Filter: 4
Planning Time: 3.361 ms
Execution Time: 0.048 ms
(5 rows)
db=# set enable_seqscan=off; (fullscan)
SET
db=# explain analyze select * from points where p <@ box '(2,1),(7,4)';
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------
Index Only Scan using points_p_idx on points (cost=0.13..8.15 rows=1 width=16) (actual time=0.269..0.271 rows=2 loops=1)
Index Cond: (p <@ '(7,4),(2,1)'::box)
Heap Fetches: 2
Planning Time: 0.145 ms
Execution Time: 0.313 ms
(5 rows)
db=# explain (costs off) select * from points where p <@ box '(2,1),(7,4)';
QUERY PLAN
----------------------------------------------
Index Only Scan using points_p_idx on points
Index Cond: (p <@ '(7,4),(2,1)'::box)
(2 rows)
Example:point,line,box,circle
sp-gist :
SP-GiST is an abbreviation for space-partitioned GiST. SP-GiST supports partitioned search trees,
which facilitate development of a wide range of different non-balanced data structures, such as quad-trees, k-d trees,
and radix trees (tries).
which support indexed queries using these operators:
<<
>>
~=
<@
<^
>^
Example::
==========
postgres=# create table points(p point);
CREATE TABLE
postgres=# insert into points(p) values
postgres-# (point '(1,1)'), (point '(3,2)'), (point '(6,3)'),
postgres-# (point '(5,5)'), (point '(7,8)'), (point '(8,6)');
INSERT 0 6
postgres=# select amop.amopopr::regoperator, amop.amopstrategy
from pg_opclass opc, pg_opfamily opf, pg_am am, pg_amop amop
where opc.opcname = 'quad_point_ops'
and opf.oid = opc.opcfamily
and am.oid = opf.opfmethod
and amop.amopfamily = opc.opcfamily
and am.amname = 'spgist'
and amop.amoplefttype = opc.opcintype;
amopopr | amopstrategy
-----------------+--------------
<<(point,point) | 1
>>(point,point) | 5
~=(point,point) | 6
<^(point,point) | 10
>^(point,point) | 11
<@(poin t,box) | 8
(6 rows)
postgres=# explain (costs off) select * from points where p >^ point '(2,7)';
QUERY PLAN
---------------------------------
Seq Scan on points
Filter: (p >^ '(2,7)'::point)
(2 rows)
postgres=# set enable_seqscan = off;
SET
postgres=# explain (costs off) select * from points where p >^ point '(2,7)';
QUERY PLAN
---------------------------------
Seq Scan on points
Filter: (p >^ '(2,7)'::point)
(2 rows)
postgres=# create index points_quad_idx on points using spgist(p);
CREATE INDEX
postgres=# explain (costs off) select * from points where p >^ point '(2,7)';
QUERY PLAN
-------------------------------------------------
Index Only Scan using points_quad_idx on points
Index Cond: (p >^ '(2,7)'::point)
(2 rows)