Re: [PROPOSAL] Covering + unique indexes. - Mailing list pgsql-hackers

From Anastasia Lubennikova
Subject Re: [PROPOSAL] Covering + unique indexes.
Date
Msg-id 55F84DF4.5030207@postgrespro.ru
Whole thread Raw
In response to [PROPOSAL] Covering + unique indexes.  (Anastasia Lubennikova <a.lubennikova@postgrespro.ru>)
Responses Re: [PROPOSAL] Covering + unique indexes.  (Rod Taylor <rod.taylor@gmail.com>)
Re: [PROPOSAL] Covering + unique indexes.  (José Luis Tallón <jltallon@adv-solutions.net>)
List pgsql-hackers
Proposal Clarification.<br /> I see that discussion become too <span class="b-translation__text">complicated. So, I'd
liketo clarify what we are talking about.<br /><br /> We are discussing 2 different improvements of index.<br /> The
one is "partially unique index" and the other  "index with included columns".<br /> Let's look at example.<br /><br />
-We have a table tbl(f1, f2, f3, f4).<br /> - We want to have an unique index on (f1,f2).<br /> - We want to have an
indexon (f1, f2, f3) which allow us to use index for complex "where" clauses.<br /> - We would like to have a covering
indexon all columns to avoid reading of heap pages.<br /><br /> What are we doing now:<br /> CREATE UNIQUE INDEX on
tbl(f1,f2);<br/> CREATE INDEX on tbl(f1, f2, f3, f4);<br /><br /> What's wrong? <br /> - Two indexes with repeated
data.</span>Overhead to data manipulation operations and database size.<br /> - We don't need f4 as index key. But we
haveto...<br /> - Problem related to previous. It's possible that f4 has no opclass for our index. So there's no way to
includeit to index.<br /> While we don't need any opclass at all.<br /><br /> Suggestions.<br /> CREATE INDEX idx ON
tbl(f1, f2, f3) [UNIQUE ON (f1, f2)] [INCLUDE (f4)];<br /> Let's review it step<span
class="b-translation__translation-words"><spanclass="b-translation__text"> by step.<br /><br /></span></span>1. "<span
class="b-translation__text">partiallyunique index</span>"<br /> CREATE INDEX idx ON tbl (f1, f2, f3) UNIQUE ON (f1,
f2);<br/> It means that we want to have columns (f1, f2, f3) as index keys in our index. <br /> But we want enforce
uniquenessonly on first two.<br /> It allows us insert (1,1,1), (1,2,1) and restricts insert (1,1,1), (1,1,2).<br /><br
/>It doesn't affect "select" queries.<br /> Following query can use index-only scan.<br /> SELECT f1,f2, f3 where f1
...and f2 ... and f3 ....;<br /><br /> We haven't to maintain two indexes now. Just one!<br /><br /><a
href="http://doxygen.postgresql.org/nbtinsert_8c.html#abcfb7a3dcd40a5d1759652239f3a0115">_bt_iseual()</a>works with
(f1,f2) <br /><a
href="http://doxygen.postgresql.org/nbtsearch_8c.html#af689dabb25e99f551b68aa9b7a1e6ea6">_bt_compare()</a>works with
(f1,f2,f3)<br/><br /> 2. <span class="b-translation__text">"index with included columns" It goes well with both unique
andnon-unique indexes.</span><br /> CREATE INDEX idx ON tbl (f1, f2, f3) INCLUDE (f4);<br /> What we get here:<br /> -
f4is not search key.<br /> - f4 could not have opclass for our index<br /> - f4 is only in the leaf pages and it's not
bloatinginternal nodes of b-tree.<br /> - f4 can still be retrieved without going to the heap, so including it<br /> in
theleaf nodes makes it possible to do index-only scans more often<br /><br /> Following query can use index-only
scan:<br/> SELECT f1,f2, f3, f4 where f1 ... and f2 ... and f3 ....;<br /><br /> And this one wouldn't use index-only
scanbecause recheck on f4 is required.<br /> SELECT f1,f2, f3, f4 where f1 ... and f2 ... and f3 .... and f4;<br /><br
/><br/> Catalog changes:<br /> Now:<span class="comment"></span><br /><a
href="http://doxygen.postgresql.org/pg__index_8h.html#a5065be0408f03576083a30c97b43a09a">pg_index</a><br/><span
class="lineno"></span>int16 indnatts; <span class="comment">/* number of columns in index */</span><span
class="lineno"><br/></span><span class="keywordtype">bool</span> indisunique; <span class="comment">/* is this a unique
index?*/</span><span class="comment"></span><br /><br /> New:<br /> pg_index<br /> int16 ind_n_unique_atts; /* number
ofunique columns in index. counted from begin of index. 0 means that index is not unique */<br /> int16 ind_n_key_atts;
/*number of index key columns in index. counted from begin of index.*/<br /> int16 ind_n_total_atts; /* number of
columnsin index.*/<br /><br /> In our case:<br /> ind_n_unique_atts = 2; // f1, f2<br /> ind_n_key_atts = 3; // f1, f2,
f3<br/> ind_n_total_atts = 4; // f1, f2, f3, f4<br /><br /><br /> P.S. <span class="b-translation__text">I use many
ideasfrom discussion without quotations just because I'd like to keep this message readable. Thanks to everyone.</span>
<preclass="moz-signature" cols="72">-- 
 
Anastasia Lubennikova
Postgres Professional: <a class="moz-txt-link-freetext"
href="http://www.postgrespro.com">http://www.postgrespro.com</a>
The Russian Postgres Company</pre>

pgsql-hackers by date:

Previous
From: Andres Freund
Date:
Subject: Re: Move PinBuffer and UnpinBuffer to atomics
Next
From: Michael Paquier
Date:
Subject: Re: Small typo in timeline.h regarding the meaning of infinity for timeline history entry