On 24 June 2014 23:22, Simon Riggs <si...@2ndquadrant.com> wrote: >> On a more positive or even slightly exciting note I think I've managed to >> devise a way that ANTI JOINS can be used for NOT IN much more often. It >> seems that find_nonnullable_vars will analyse a quals list to find >> expressions that mean that the var cannot be NULL. This means we can perform >> ANTI JOINS for NOT IN with queries like: >> >> SELECT * FROM a WHERE id NOT IN(SELECT nullable_col FROM b WHERE >> nullable_col = 1); >> or >> SELECT * FROM a WHERE id NOT IN(SELECT nullable_col FROM b WHERE >> nullable_col IS NOT NULL); >> >> (The attached patch implements this) >> >> the nullable_col =1 will mean that nullable_col cannot be NULL, so the ANTI >> JOIN can be performed safely. I think this combined with the NOT NULL check >> will cover probably just about all valid uses of NOT IN with a subquery... >> unless of course I've assumed something wrongly about find_nonnullable_vars. >> I just need the correct RangeTblEntry in order to determine if the >> TargetEntry is from an out join. > > This is the better way to go. It's much better to have explicit proof > its not null than a possibly long chain of metadata that might be > buggy. > >> The attached patch is a broken implemention that still needs the lookup code >> fixed to reference the correct RTE. The failing regression tests show where >> the problems lie. >> >> Any help on this would be really appreciated. > > I'd suggest we just drop the targetlist approach completely.
To be clearer, what I mean is we use only the direct proof approach, for queries like this SELECT * FROM a WHERE id NOT IN(SELECT unknown_col FROM b WHERE unknown_col IS NOT NULL); and we don't try to do it for queries like this SELECT * FROM a WHERE id NOT IN(SELECT not_null_column FROM b); because we don't know the full provenance of "not_null_column" in all cases and that info is (currently) unreliable. Once we have the transform working for one case, we can try to extend the cases covered. -- Simon Riggs http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Training & Services -- Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-hackers