Re: Querying foreign table with SP-GiST index results in “ERROR: cache lookup failed for type 0”
От | Etsuro Fujita |
---|---|
Тема | Re: Querying foreign table with SP-GiST index results in “ERROR: cache lookup failed for type 0” |
Дата | |
Msg-id | CAPmGK16s=M3P28tP_XRiWT49nYysa72MOx57VWWA_VJekrkCNQ@mail.gmail.com обсуждение исходный текст |
Ответ на | Re: Querying foreign table with SP-GiST index results in “ERROR: cache lookup failed for type 0” (Etsuro Fujita <etsuro.fujita@gmail.com>) |
Ответы |
Re: Re: Querying foreign table with SP-GiST index results in “ERROR: cache lookup failed for type 0”
|
Список | pgsql-bugs |
On Thu, Jun 20, 2019 at 6:16 PM Etsuro Fujita <etsuro.fujita@gmail.com> wrote: > On Tue, Jun 18, 2019 at 9:22 PM Jeff Janes <jeff.janes@gmail.com> wrote: > > On Tue, Jun 18, 2019 at 8:02 AM Joao Ferreira <jpgferreira@yahoo.com> wrote: > >> I'm using PostgreSQL 11.3 and I want to access a table in another Postgres database using postgres_fdw but since theoriginal table has an SP-GiST index on a geometry column, the query on the foreign table fails with "ERROR: cache lookupfailed for type 0", even if the table is empty (Step 7). This doesn't happen if the query is done directly to the remotetable (Steps 3 and 6) or if the remote table doesn't have the index (Steps 3 and 4). > > I've verified this on ubuntu 18.04 with 11.3 installed from PGDG apt repo, and attached a single-file reproduction. > > I've also verified this on my environment with PG 11.4. > > > If I change from sp-gist to just gist, there is no problem. And if I change to indexing a built-in sp-gist operatorclass (point rather than geom), there is also no problem. > > Verified. > > Will continue investigations. I found that this error is thrown by index_can_return() (spgcanreturn()) called from get_relation_info() for the SP-GiST index on the locations table. IIUC, the cause of that is: the SP-GiST config function defined in PostGIS shown below called from spgGetCache() in spgcanreturn() doesn't work well for the postgres_fdw case, in which case cfg->prefixType and cfg->leafType are set to InvalidOid, causing the "ERROR: cache lookup failed for type 0" error in fillTypeDesc() callled later in spgGetCache() for the cfg->prefixType, because TypenameGetTypid() returns InvalidOid in that case since that in postgres_fdw we run the connection with search_path restricted to pg_catalog while box2df is created in the public schema in an environment built using a PostGIS default configuration. PGDLLEXPORT Datum gserialized_spgist_config_2d(PG_FUNCTION_ARGS) { spgConfigOut *cfg = (spgConfigOut *)PG_GETARG_POINTER(1); --> Oid boxoid = TypenameGetTypid("box2df"); cfg->prefixType = boxoid; cfg->labelType = VOIDOID; /* We don't need node labels. */ cfg->leafType = boxoid; cfg->canReturnData = false; cfg->longValuesOK = false; PG_RETURN_VOID(); } I'm a newbie to PostGIS, so maybe I'm missing something, but isn't it a bit fragile to use TypenameGetTypid() here? I just thought it would be better to set boxoid in a more hard-coded way in this function, not using TypenameGetTypid(). Best regards, Etsuro Fujita
В списке pgsql-bugs по дате отправления: