How does the planner know that the function used in an index has changed? If the function's body is changed keeping the argument and return types the planner will not use it anymore:
create table t (i integer);
insert into t (i)
select generate_series(1, 100000);
analyze t;
A simple function to return the opposite integer:
create or replace function f(i integer)
returns integer as $$
select i * -1;
$$ immutable language sql;
And the index on it:
create index t_i_index on t(f(i));
The index is used:
explain select * from t order by f(i);
QUERY PLAN
---------------------------------------------------------------------------
Index Scan using t_i_index on t (cost=0.00..3300.26 rows=100000 width=4)
Now the function is changed to return the integer itself:
create or replace function f(i integer)
returns integer as $$
select i;
$$ immutable language sql;
And the index is not used anymore:
explain select * from t order by f(i);
QUERY PLAN
---------------------------------------------------------------
Sort (cost=11116.32..11366.32 rows=100000 width=4)
Sort Key: i
-> Seq Scan on t (cost=0.00..1443.00 rows=100000 width=4)
If the index is rebuilt
reindex index t_i_index;
It is used again:
explain select * from t order by f(i);
QUERY PLAN
---------------------------------------------------------------------------
Index Scan using t_i_index on t (cost=0.00..4376.26 rows=100000 width=4)
Regards, Clodoaldo
create table t (i integer);
insert into t (i)
select generate_series(1, 100000);
analyze t;
A simple function to return the opposite integer:
create or replace function f(i integer)
returns integer as $$
select i * -1;
$$ immutable language sql;
And the index on it:
create index t_i_index on t(f(i));
The index is used:
explain select * from t order by f(i);
QUERY PLAN
---------------------------------------------------------------------------
Index Scan using t_i_index on t (cost=0.00..3300.26 rows=100000 width=4)
Now the function is changed to return the integer itself:
create or replace function f(i integer)
returns integer as $$
select i;
$$ immutable language sql;
And the index is not used anymore:
explain select * from t order by f(i);
QUERY PLAN
---------------------------------------------------------------
Sort (cost=11116.32..11366.32 rows=100000 width=4)
Sort Key: i
-> Seq Scan on t (cost=0.00..1443.00 rows=100000 width=4)
If the index is rebuilt
reindex index t_i_index;
It is used again:
explain select * from t order by f(i);
QUERY PLAN
---------------------------------------------------------------------------
Index Scan using t_i_index on t (cost=0.00..4376.26 rows=100000 width=4)
Regards, Clodoaldo