mirror of
				https://github.com/postgres/postgres.git
				synced 2025-10-31 00:03:57 -04:00 
			
		
		
		
	Make 'col IS NULL' clauses be indexable conditions.
Teodor Sigaev, with some kibitzing from Tom Lane.
This commit is contained in:
		
							parent
							
								
									146c83c045
								
							
						
					
					
						commit
						f02a82b6ad
					
				| @ -1,4 +1,4 @@ | ||||
| <!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.149 2007/04/02 03:49:36 tgl Exp $ --> | ||||
| <!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.150 2007/04/06 22:33:41 tgl Exp $ --> | ||||
| <!-- | ||||
|  Documentation of the system catalogs, directed toward PostgreSQL developers | ||||
|  --> | ||||
| @ -405,6 +405,13 @@ | ||||
|       <entry>Does the access method support null index entries?</entry> | ||||
|      </row> | ||||
| 
 | ||||
|      <row> | ||||
|       <entry><structfield>amsearchnulls</structfield></entry> | ||||
|       <entry><type>bool</type></entry> | ||||
|       <entry></entry> | ||||
|       <entry>Does the access method support IS NULL searches?</entry> | ||||
|      </row> | ||||
| 
 | ||||
|      <row> | ||||
|       <entry><structfield>amstorage</structfield></entry> | ||||
|       <entry><type>bool</type></entry> | ||||
|  | ||||
| @ -1,4 +1,4 @@ | ||||
| <!-- $PostgreSQL: pgsql/doc/src/sgml/indexam.sgml,v 2.22 2007/02/22 22:00:22 tgl Exp $ --> | ||||
| <!-- $PostgreSQL: pgsql/doc/src/sgml/indexam.sgml,v 2.23 2007/04/06 22:33:41 tgl Exp $ --> | ||||
| 
 | ||||
| <chapter id="indexam"> | ||||
|  <title>Index Access Method Interface Definition</title> | ||||
| @ -129,7 +129,10 @@ | ||||
|    It is, however, OK to omit rows where the first indexed column is null. | ||||
|    Thus, <structfield>amindexnulls</structfield> should be set true only if the | ||||
|    index access method indexes all rows, including arbitrary combinations of | ||||
|    null values. | ||||
|    null values.  An index access method that sets | ||||
|    <structfield>amindexnulls</structfield> may also set | ||||
|    <structfield>amsearchnulls</structfield>, indicating that it supports | ||||
|    <literal>IS NULL</> clauses as search conditions. | ||||
|   </para> | ||||
| 
 | ||||
|  </sect1> | ||||
|  | ||||
| @ -1,4 +1,4 @@ | ||||
| <!-- $PostgreSQL: pgsql/doc/src/sgml/indices.sgml,v 1.70 2007/02/14 20:47:15 tgl Exp $ --> | ||||
| <!-- $PostgreSQL: pgsql/doc/src/sgml/indices.sgml,v 1.71 2007/04/06 22:33:41 tgl Exp $ --> | ||||
| 
 | ||||
| <chapter id="indexes"> | ||||
|  <title id="indexes-title">Indexes</title> | ||||
| @ -147,8 +147,8 @@ CREATE INDEX test1_id_index ON test1 (id); | ||||
| 
 | ||||
|    Constructs equivalent to combinations of these operators, such as | ||||
|    <literal>BETWEEN</> and <literal>IN</>, can also be implemented with | ||||
|    a B-tree index search.  (But note that <literal>IS NULL</> is not | ||||
|    equivalent to <literal>=</> and is not indexable.) | ||||
|    a B-tree index search.  Also, an <literal>IS NULL</> condition on | ||||
|    an index column can be used with a B-tree index. | ||||
|   </para> | ||||
| 
 | ||||
|   <para> | ||||
| @ -180,8 +180,9 @@ CREATE INDEX test1_id_index ON test1 (id); | ||||
|    Hash indexes can only handle simple equality comparisons. | ||||
|    The query planner will consider using a hash index whenever an | ||||
|    indexed column is involved in a comparison using the | ||||
|    <literal>=</literal> operator.  The following command is used to | ||||
|    create a hash index: | ||||
|    <literal>=</literal> operator.  (But hash indexes do not support | ||||
|    <literal>IS NULL</> searches.) | ||||
|    The following command is used to create a hash index: | ||||
| <synopsis> | ||||
| CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> USING hash (<replaceable>column</replaceable>); | ||||
| </synopsis> | ||||
| @ -234,6 +235,8 @@ CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> | ||||
| 
 | ||||
|    (See <xref linkend="functions-geometry"> for the meaning of | ||||
|    these operators.) | ||||
|    Also, an <literal>IS NULL</> condition on | ||||
|    an index column can be used with a GiST index. | ||||
|    Many other GiST operator | ||||
|    classes are available in the <literal>contrib</> collection or as separate | ||||
|    projects.  For more information see <xref linkend="GiST">. | ||||
| @ -266,6 +269,7 @@ CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> | ||||
| 
 | ||||
|    (See <xref linkend="functions-array"> for the meaning of | ||||
|    these operators.) | ||||
|    GIN indexes cannot use <literal>IS NULL</> as a search condition. | ||||
|    Other GIN operator classes are available in the <literal>contrib</> | ||||
|    <literal>tsearch2</literal> and <literal>intarray</literal> modules. | ||||
|    For more information see <xref linkend="GIN">. | ||||
|  | ||||
| @ -1,5 +1,5 @@ | ||||
| <!-- | ||||
| $PostgreSQL: pgsql/doc/src/sgml/ref/create_index.sgml,v 1.61 2007/04/03 22:38:35 momjian Exp $ | ||||
| $PostgreSQL: pgsql/doc/src/sgml/ref/create_index.sgml,v 1.62 2007/04/06 22:33:41 tgl Exp $ | ||||
| PostgreSQL documentation | ||||
| --> | ||||
| 
 | ||||
| @ -434,12 +434,6 @@ Indexes: | ||||
|    to remove an index. | ||||
|   </para> | ||||
| 
 | ||||
|   <para> | ||||
|    Indexes are not used for <literal>IS NULL</> clauses by default. | ||||
|    The best way to use indexes in such cases is to create a partial index | ||||
|    using an <literal>IS NULL</> predicate. | ||||
|   </para> | ||||
| 
 | ||||
|   <para> | ||||
|    Prior releases of <productname>PostgreSQL</productname> also had an | ||||
|    R-tree index method.  This method has been removed because | ||||
|  | ||||
| @ -8,7 +8,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/common/scankey.c,v 1.29 2007/01/05 22:19:21 momjian Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/common/scankey.c,v 1.30 2007/04/06 22:33:41 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -20,7 +20,8 @@ | ||||
| /*
 | ||||
|  * ScanKeyEntryInitialize | ||||
|  *		Initializes a scan key entry given all the field values. | ||||
|  *		The target procedure is specified by OID. | ||||
|  *		The target procedure is specified by OID (but can be invalid | ||||
|  *		if SK_SEARCHNULL is set). | ||||
|  * | ||||
|  * Note: CurrentMemoryContext at call should be as long-lived as the ScanKey | ||||
|  * itself, because that's what will be used for any subsidiary info attached | ||||
| @ -40,7 +41,13 @@ ScanKeyEntryInitialize(ScanKey entry, | ||||
| 	entry->sk_strategy = strategy; | ||||
| 	entry->sk_subtype = subtype; | ||||
| 	entry->sk_argument = argument; | ||||
| 	if (RegProcedureIsValid(procedure)) | ||||
| 		fmgr_info(procedure, &entry->sk_func); | ||||
| 	else | ||||
| 	{ | ||||
| 		Assert(flags & SK_SEARCHNULL); | ||||
| 		MemSet(&entry->sk_func, 0, sizeof(entry->sk_func)); | ||||
| 	} | ||||
| } | ||||
| 
 | ||||
| /*
 | ||||
|  | ||||
| @ -8,7 +8,7 @@ | ||||
|  * Portions Copyright (c) 1994, Regents of the University of California | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/gist/gistget.c,v 1.64 2007/01/20 18:43:35 neilc Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/gist/gistget.c,v 1.65 2007/04/06 22:33:41 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -381,16 +381,23 @@ gistindex_keytest(IndexTuple tuple, | ||||
| 		if (key->sk_flags & SK_ISNULL) | ||||
| 		{ | ||||
| 			/*
 | ||||
| 			 * is the compared-to datum NULL? on non-leaf page it's possible | ||||
| 			 * to have nulls in childs :( | ||||
| 			 * On non-leaf page we can't conclude that child hasn't NULL | ||||
| 			 * values because of assumption in GiST: uinon (VAL, NULL) is VAL | ||||
| 			 * But if on non-leaf page key IS  NULL then all childs | ||||
| 			 * has NULL. | ||||
| 			 */ | ||||
| 
 | ||||
| 			if (isNull || !GistPageIsLeaf(p)) | ||||
| 				return true; | ||||
| 			Assert( key->sk_flags & SK_SEARCHNULL ); | ||||
| 
 | ||||
| 			if ( GistPageIsLeaf(p) && !isNull ) | ||||
| 				return false; | ||||
| 		} | ||||
| 		else if (isNull) | ||||
| 		{ | ||||
| 			return false; | ||||
| 		} | ||||
| 		else | ||||
| 		{ | ||||
| 
 | ||||
| 			gistdentryinit(giststate, key->sk_attno - 1, &de, | ||||
| 						   datum, r, p, offset, | ||||
| @ -412,6 +419,7 @@ gistindex_keytest(IndexTuple tuple, | ||||
| 
 | ||||
| 			if (!DatumGetBool(test)) | ||||
| 				return false; | ||||
| 		} | ||||
| 
 | ||||
| 		keySize--; | ||||
| 		key++; | ||||
|  | ||||
| @ -8,7 +8,7 @@ | ||||
|  * Portions Copyright (c) 1994, Regents of the University of California | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/nbtree/nbtsearch.c,v 1.111 2007/01/09 02:14:10 tgl Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/nbtree/nbtsearch.c,v 1.112 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -746,8 +746,6 @@ _bt_first(IndexScanDesc scan, ScanDirection dir) | ||||
| 	 * | ||||
| 	 * If goback = true, we will then step back one item, while if | ||||
| 	 * goback = false, we will start the scan on the located item. | ||||
| 	 * | ||||
| 	 * it's yet other place to add some code later for is(not)null ... | ||||
| 	 *---------- | ||||
| 	 */ | ||||
| 	switch (strat_total) | ||||
|  | ||||
| @ -8,7 +8,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/nbtree/nbtutils.c,v 1.83 2007/03/30 00:12:59 tgl Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/access/nbtree/nbtutils.c,v 1.84 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -264,12 +264,27 @@ _bt_preprocess_keys(IndexScanDesc scan) | ||||
| 	if (numberOfKeys == 1) | ||||
| 	{ | ||||
| 		/*
 | ||||
| 		 * We don't use indices for 'A is null' and 'A is not null' currently | ||||
| 		 * and 'A < = > <> NULL' will always fail - so qual is not OK if | ||||
| 		 * comparison value is NULL.	  - vadim 03/21/97 | ||||
| 		 * We treat all btree operators as strict (even if they're not so | ||||
| 		 * marked in pg_proc).  This means that it is impossible for an | ||||
| 		 * operator condition with a NULL comparison constant to succeed, | ||||
| 		 * and we can reject it right away. | ||||
| 		 * | ||||
| 		 * However, we now also support "x IS NULL" clauses as search | ||||
| 		 * conditions, so in that case keep going.  The planner has not | ||||
| 		 * filled in any particular strategy in this case, so set it to | ||||
| 		 * BTEqualStrategyNumber --- we can treat IS NULL as an equality | ||||
| 		 * operator for purposes of search strategy. | ||||
| 		 */ | ||||
| 		if (cur->sk_flags & SK_ISNULL) | ||||
| 		{ | ||||
| 			if (cur->sk_flags & SK_SEARCHNULL) | ||||
| 			{ | ||||
| 				cur->sk_strategy = BTEqualStrategyNumber; | ||||
| 				cur->sk_subtype = InvalidOid; | ||||
| 			} | ||||
| 			else | ||||
| 				so->qual_ok = false; | ||||
| 		} | ||||
| 		_bt_mark_scankey_with_indoption(cur, indoption); | ||||
| 		memcpy(outkeys, cur, sizeof(ScanKeyData)); | ||||
| 		so->numberOfKeys = 1; | ||||
| @ -303,19 +318,22 @@ _bt_preprocess_keys(IndexScanDesc scan) | ||||
| 	{ | ||||
| 		if (i < numberOfKeys) | ||||
| 		{ | ||||
| 			/* See comments above: any NULL implies cannot match qual */ | ||||
| 			/* See comments above about NULLs and IS NULL handling. */ | ||||
| 			/* Note: we assume SK_ISNULL is never set in a row header key */ | ||||
| 			if (cur->sk_flags & SK_ISNULL) | ||||
| 			{ | ||||
| 				if (cur->sk_flags & SK_SEARCHNULL) | ||||
| 				{ | ||||
| 					cur->sk_strategy = BTEqualStrategyNumber; | ||||
| 					cur->sk_subtype = InvalidOid; | ||||
| 				} | ||||
| 				else | ||||
| 				{ | ||||
| 					so->qual_ok = false; | ||||
| 
 | ||||
| 				/*
 | ||||
| 				 * Quit processing so we don't try to invoke comparison | ||||
| 				 * routines on NULLs. | ||||
| 				 */ | ||||
| 					return; | ||||
| 				} | ||||
| 			} | ||||
| 		} | ||||
| 
 | ||||
| 		/*
 | ||||
| 		 * If we are at the end of the keys for a particular attr, finish up | ||||
| @ -344,6 +362,14 @@ _bt_preprocess_keys(IndexScanDesc scan) | ||||
| 
 | ||||
| 					if (!chk || j == (BTEqualStrategyNumber - 1)) | ||||
| 						continue; | ||||
| 
 | ||||
| 					/* IS NULL together with any other predicate must fail */ | ||||
| 					if (eq->sk_flags & SK_SEARCHNULL) | ||||
| 					{ | ||||
| 						so->qual_ok = false; | ||||
| 						return; | ||||
| 					} | ||||
| 
 | ||||
| 					if (_bt_compare_scankey_args(scan, chk, eq, chk, | ||||
| 												 &test_result)) | ||||
| 					{ | ||||
| @ -455,6 +481,23 @@ _bt_preprocess_keys(IndexScanDesc scan) | ||||
| 		else | ||||
| 		{ | ||||
| 			/* yup, keep only the more restrictive key */ | ||||
| 
 | ||||
| 			/* if either arg is NULL, don't try to compare */ | ||||
| 			if ((cur->sk_flags | xform[j]->sk_flags) & SK_ISNULL) | ||||
| 			{ | ||||
| 				/* at least one of them must be an IS NULL clause */ | ||||
| 				Assert(j == (BTEqualStrategyNumber - 1)); | ||||
| 				Assert((cur->sk_flags | xform[j]->sk_flags) & SK_SEARCHNULL); | ||||
| 				/* if one is and one isn't, the search must fail */ | ||||
| 				if ((cur->sk_flags ^ xform[j]->sk_flags) & SK_SEARCHNULL) | ||||
| 				{ | ||||
| 					so->qual_ok = false; | ||||
| 					return; | ||||
| 				} | ||||
| 				/* we have duplicate IS NULL clauses, ignore the newer one */ | ||||
| 				continue; | ||||
| 			} | ||||
| 
 | ||||
| 			if (_bt_compare_scankey_args(scan, cur, cur, xform[j], | ||||
| 										 &test_result)) | ||||
| 			{ | ||||
| @ -798,11 +841,29 @@ _bt_checkkeys(IndexScanDesc scan, | ||||
| 							  tupdesc, | ||||
| 							  &isNull); | ||||
| 
 | ||||
| 		/* btree doesn't support 'A is null' clauses, yet */ | ||||
| 		if (key->sk_flags & SK_ISNULL) | ||||
| 		{ | ||||
| 			/* we shouldn't get here, really; see _bt_preprocess_keys() */ | ||||
| 			/* Handle IS NULL tests */ | ||||
| 			Assert(key->sk_flags & SK_SEARCHNULL); | ||||
| 
 | ||||
| 			if (isNull) | ||||
| 				continue;		/* tuple satisfies this qual */ | ||||
| 
 | ||||
| 			/*
 | ||||
| 			 * Tuple fails this qual.  If it's a required qual for the current | ||||
| 			 * scan direction, then we can conclude no further tuples will | ||||
| 			 * pass, either. | ||||
| 			 */ | ||||
| 			if ((key->sk_flags & SK_BT_REQFWD) && | ||||
| 				ScanDirectionIsForward(dir)) | ||||
| 				*continuescan = false; | ||||
| 			else if ((key->sk_flags & SK_BT_REQBKWD) && | ||||
| 					 ScanDirectionIsBackward(dir)) | ||||
| 				*continuescan = false; | ||||
| 
 | ||||
| 			/*
 | ||||
| 			 * In any case, this indextuple doesn't match the qual. | ||||
| 			 */ | ||||
| 			return false; | ||||
| 		} | ||||
| 
 | ||||
|  | ||||
| @ -8,7 +8,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/executor/nodeIndexscan.c,v 1.120 2007/01/05 22:19:28 momjian Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/executor/nodeIndexscan.c,v 1.121 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -599,7 +599,7 @@ ExecInitIndexScan(IndexScan *node, EState *estate, int eflags) | ||||
|  * The index quals are passed to the index AM in the form of a ScanKey array. | ||||
|  * This routine sets up the ScanKeys, fills in all constant fields of the | ||||
|  * ScanKeys, and prepares information about the keys that have non-constant | ||||
|  * comparison values.  We divide index qual expressions into four types: | ||||
|  * comparison values.  We divide index qual expressions into five types: | ||||
|  * | ||||
|  * 1. Simple operator with constant comparison value ("indexkey op constant"). | ||||
|  * For these, we just fill in a ScanKey containing the constant value. | ||||
| @ -620,6 +620,8 @@ ExecInitIndexScan(IndexScan *node, EState *estate, int eflags) | ||||
|  * (Note that we treat all array-expressions as requiring runtime evaluation, | ||||
|  * even if they happen to be constants.) | ||||
|  * | ||||
|  * 5. NullTest ("indexkey IS NULL").  We just fill in the ScanKey properly. | ||||
|  * | ||||
|  * Input params are: | ||||
|  * | ||||
|  * planstate: executor state node we are working for | ||||
| @ -956,6 +958,38 @@ ExecIndexBuildScanKeys(PlanState *planstate, Relation index, | ||||
| 								   opfuncid,	/* reg proc to use */ | ||||
| 								   (Datum) 0);	/* constant */ | ||||
| 		} | ||||
| 		else if (IsA(clause, NullTest)) | ||||
| 		{ | ||||
| 			/* indexkey IS NULL */ | ||||
| 			Assert(((NullTest *) clause)->nulltesttype == IS_NULL); | ||||
| 
 | ||||
| 			/*
 | ||||
| 			 * argument should be the index key Var, possibly relabeled | ||||
| 			 */ | ||||
| 			leftop = ((NullTest *) clause)->arg; | ||||
| 
 | ||||
| 			if (leftop && IsA(leftop, RelabelType)) | ||||
| 				leftop = ((RelabelType *) leftop)->arg; | ||||
| 
 | ||||
| 			 Assert(leftop != NULL); | ||||
| 
 | ||||
| 			if (!(IsA(leftop, Var) && | ||||
| 				  var_is_rel((Var *) leftop))) | ||||
| 				elog(ERROR, "NullTest indexqual has wrong key"); | ||||
| 
 | ||||
| 			varattno = ((Var *) leftop)->varattno; | ||||
| 
 | ||||
| 			/*
 | ||||
| 			 * initialize the scan key's fields appropriately | ||||
| 			 */ | ||||
| 			ScanKeyEntryInitialize(this_scan_key, | ||||
| 								   SK_ISNULL | SK_SEARCHNULL, | ||||
| 								   varattno,    /* attribute number to scan */ | ||||
| 								   strategy,    /* op's strategy */ | ||||
| 								   subtype,		/* strategy subtype */ | ||||
| 								   InvalidOid,	/* no reg proc for this */ | ||||
| 								   (Datum) 0);	/* constant */ | ||||
| 		} | ||||
| 		else | ||||
| 			elog(ERROR, "unsupported indexqual type: %d", | ||||
| 				 (int) nodeTag(clause)); | ||||
|  | ||||
| @ -9,7 +9,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/optimizer/path/indxpath.c,v 1.218 2007/03/21 22:18:12 tgl Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/optimizer/path/indxpath.c,v 1.219 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -1050,6 +1050,7 @@ match_clause_to_indexcol(IndexOptInfo *index, | ||||
| 	 * Clause must be a binary opclause, or possibly a ScalarArrayOpExpr | ||||
| 	 * (which is always binary, by definition).  Or it could be a | ||||
| 	 * RowCompareExpr, which we pass off to match_rowcompare_to_indexcol(). | ||||
| 	 * Or, if the index supports it, we can handle IS NULL clauses. | ||||
| 	 */ | ||||
| 	if (is_opclause(clause)) | ||||
| 	{ | ||||
| @ -1083,6 +1084,15 @@ match_clause_to_indexcol(IndexOptInfo *index, | ||||
| 											(RowCompareExpr *) clause, | ||||
| 											outer_relids); | ||||
| 	} | ||||
| 	else if (index->amsearchnulls && IsA(clause, NullTest)) | ||||
| 	{ | ||||
| 		NullTest	*nt = (NullTest *) clause; | ||||
| 
 | ||||
| 		if (nt->nulltesttype == IS_NULL && | ||||
| 			match_index_to_operand((Node *) nt->arg, indexcol, index)) | ||||
| 			return true; | ||||
| 		return false; | ||||
| 	} | ||||
| 	else | ||||
| 		return false; | ||||
| 
 | ||||
| @ -2102,8 +2112,8 @@ expand_indexqual_conditions(IndexOptInfo *index, List *clausegroups) | ||||
| 			} | ||||
| 
 | ||||
| 			/*
 | ||||
| 			 * Else it must be an opclause (usual case), ScalarArrayOp, or | ||||
| 			 * RowCompare | ||||
| 			 * Else it must be an opclause (usual case), ScalarArrayOp, | ||||
| 			 * RowCompare, or NullTest | ||||
| 			 */ | ||||
| 			if (is_opclause(clause)) | ||||
| 			{ | ||||
| @ -2123,6 +2133,16 @@ expand_indexqual_conditions(IndexOptInfo *index, List *clausegroups) | ||||
| 																  index, | ||||
| 																  indexcol)); | ||||
| 			} | ||||
| 			else if (IsA(clause, NullTest)) | ||||
| 			{ | ||||
| 				Assert(index->amsearchnulls); | ||||
| 				resultquals = lappend(resultquals, | ||||
| 									  make_restrictinfo(clause, | ||||
| 														true, | ||||
| 														false, | ||||
| 														false, | ||||
| 														NULL)); | ||||
| 			} | ||||
| 			else | ||||
| 				elog(ERROR, "unsupported indexqual type: %d", | ||||
| 					 (int) nodeTag(clause)); | ||||
|  | ||||
| @ -10,7 +10,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/optimizer/plan/createplan.c,v 1.227 2007/02/25 17:44:01 tgl Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/optimizer/plan/createplan.c,v 1.228 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -18,6 +18,7 @@ | ||||
| 
 | ||||
| #include <limits.h> | ||||
| 
 | ||||
| #include "access/skey.h" | ||||
| #include "nodes/makefuncs.h" | ||||
| #include "optimizer/clauses.h" | ||||
| #include "optimizer/cost.h" | ||||
| @ -1821,6 +1822,7 @@ fix_indexqual_references(List *indexquals, IndexPath *index_path, | ||||
| 		Oid			stratlefttype; | ||||
| 		Oid			stratrighttype; | ||||
| 		bool		recheck; | ||||
| 		bool		is_null_op = false; | ||||
| 
 | ||||
| 		Assert(IsA(rinfo, RestrictInfo)); | ||||
| 
 | ||||
| @ -1907,6 +1909,17 @@ fix_indexqual_references(List *indexquals, IndexPath *index_path, | ||||
| 														 &opfamily); | ||||
| 			clause_op = saop->opno; | ||||
| 		} | ||||
| 		else if (IsA(clause, NullTest)) | ||||
| 		{ | ||||
| 			NullTest *nt = (NullTest *) clause; | ||||
| 
 | ||||
| 			Assert(nt->nulltesttype == IS_NULL); | ||||
| 			nt->arg = (Expr *) fix_indexqual_operand((Node *) nt->arg, | ||||
| 													 index, | ||||
| 													 &opfamily); | ||||
| 			is_null_op = true; | ||||
| 			clause_op = InvalidOid;		/* keep compiler quiet */ | ||||
| 		} | ||||
| 		else | ||||
| 		{ | ||||
| 			elog(ERROR, "unsupported indexqual type: %d", | ||||
| @ -1916,9 +1929,19 @@ fix_indexqual_references(List *indexquals, IndexPath *index_path, | ||||
| 
 | ||||
| 		*fixed_indexquals = lappend(*fixed_indexquals, clause); | ||||
| 
 | ||||
| 		if (is_null_op) | ||||
| 		{ | ||||
| 			/* IS NULL doesn't have a clause_op */ | ||||
| 			stratno = InvalidStrategy; | ||||
| 			stratrighttype = InvalidOid; | ||||
| 			/* We assume it's non-lossy ... might need more work someday */ | ||||
| 			recheck = false; | ||||
| 		} | ||||
| 		else | ||||
| 		{ | ||||
| 			/*
 | ||||
| 		 * Look up the (possibly commuted) operator in the operator family to | ||||
| 		 * get its strategy number and the recheck indicator.	This also | ||||
| 			 * Look up the (possibly commuted) operator in the operator family | ||||
| 			 * to get its strategy number and the recheck indicator. This also | ||||
| 			 * double-checks that we found an operator matching the index. | ||||
| 			 */ | ||||
| 			get_op_opfamily_properties(clause_op, opfamily, | ||||
| @ -1926,6 +1949,7 @@ fix_indexqual_references(List *indexquals, IndexPath *index_path, | ||||
| 									   &stratlefttype, | ||||
| 									   &stratrighttype, | ||||
| 									   &recheck); | ||||
| 		} | ||||
| 
 | ||||
| 		*indexstrategy = lappend_int(*indexstrategy, stratno); | ||||
| 		*indexsubtype = lappend_oid(*indexsubtype, stratrighttype); | ||||
|  | ||||
| @ -9,7 +9,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/optimizer/util/plancat.c,v 1.132 2007/01/20 23:13:01 tgl Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/optimizer/util/plancat.c,v 1.133 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -187,6 +187,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent, | ||||
| 			info->relam = indexRelation->rd_rel->relam; | ||||
| 			info->amcostestimate = indexRelation->rd_am->amcostestimate; | ||||
| 			info->amoptionalkey = indexRelation->rd_am->amoptionalkey; | ||||
| 			info->amsearchnulls = indexRelation->rd_am->amsearchnulls; | ||||
| 
 | ||||
| 			/*
 | ||||
| 			 * Fetch the ordering operators associated with the index, if any. | ||||
|  | ||||
| @ -15,7 +15,7 @@ | ||||
|  * | ||||
|  * | ||||
|  * IDENTIFICATION | ||||
|  *	  $PostgreSQL: pgsql/src/backend/utils/adt/selfuncs.c,v 1.231 2007/03/27 23:21:10 tgl Exp $ | ||||
|  *	  $PostgreSQL: pgsql/src/backend/utils/adt/selfuncs.c,v 1.232 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -4992,6 +4992,7 @@ btcostestimate(PG_FUNCTION_ARGS) | ||||
| 	int			indexcol; | ||||
| 	bool		eqQualHere; | ||||
| 	bool		found_saop; | ||||
| 	bool		found_null_op; | ||||
| 	double		num_sa_scans; | ||||
| 	ListCell   *l; | ||||
| 
 | ||||
| @ -5016,6 +5017,7 @@ btcostestimate(PG_FUNCTION_ARGS) | ||||
| 	indexcol = 0; | ||||
| 	eqQualHere = false; | ||||
| 	found_saop = false; | ||||
| 	found_null_op = false; | ||||
| 	num_sa_scans = 1; | ||||
| 	foreach(l, indexQuals) | ||||
| 	{ | ||||
| @ -5025,6 +5027,7 @@ btcostestimate(PG_FUNCTION_ARGS) | ||||
| 				   *rightop; | ||||
| 		Oid			clause_op; | ||||
| 		int			op_strategy; | ||||
| 		bool		is_null_op = false; | ||||
| 
 | ||||
| 		Assert(IsA(rinfo, RestrictInfo)); | ||||
| 		clause = rinfo->clause; | ||||
| @ -5051,6 +5054,17 @@ btcostestimate(PG_FUNCTION_ARGS) | ||||
| 			clause_op = saop->opno; | ||||
| 			found_saop = true; | ||||
| 		} | ||||
| 		else if (IsA(clause, NullTest)) | ||||
| 		{ | ||||
| 			NullTest   *nt = (NullTest *) clause; | ||||
| 
 | ||||
| 			Assert(nt->nulltesttype == IS_NULL); | ||||
| 			leftop = (Node *) nt->arg; | ||||
| 			rightop = NULL; | ||||
| 			clause_op = InvalidOid; | ||||
| 			found_null_op = true; | ||||
| 			is_null_op = true; | ||||
| 		} | ||||
| 		else | ||||
| 		{ | ||||
| 			elog(ERROR, "unsupported indexqual type: %d", | ||||
| @ -5088,11 +5102,20 @@ btcostestimate(PG_FUNCTION_ARGS) | ||||
| 				break; | ||||
| 			} | ||||
| 		} | ||||
| 		/* check for equality operator */ | ||||
| 		if (is_null_op) | ||||
| 		{ | ||||
| 			/* IS NULL is like = for purposes of selectivity determination */ | ||||
| 			eqQualHere = true; | ||||
| 		} | ||||
| 		else | ||||
| 		{ | ||||
| 			op_strategy = get_op_opfamily_strategy(clause_op, | ||||
| 												   index->opfamily[indexcol]); | ||||
| 			Assert(op_strategy != 0);		/* not a member of opfamily?? */ | ||||
| 			if (op_strategy == BTEqualStrategyNumber) | ||||
| 				eqQualHere = true; | ||||
| 		} | ||||
| 		/* count up number of SA scans induced by indexBoundQuals only */ | ||||
| 		if (IsA(clause, ScalarArrayOpExpr)) | ||||
| 		{ | ||||
| @ -5108,12 +5131,14 @@ btcostestimate(PG_FUNCTION_ARGS) | ||||
| 	/*
 | ||||
| 	 * If index is unique and we found an '=' clause for each column, we can | ||||
| 	 * just assume numIndexTuples = 1 and skip the expensive | ||||
| 	 * clauselist_selectivity calculations. | ||||
| 	 * clauselist_selectivity calculations.  However, a ScalarArrayOp or | ||||
| 	 * NullTest invalidates that theory, even though it sets eqQualHere. | ||||
| 	 */ | ||||
| 	if (index->unique && | ||||
| 		indexcol == index->ncolumns - 1 && | ||||
| 		eqQualHere && | ||||
| 		!found_saop) | ||||
| 		!found_saop && | ||||
| 		!found_null_op) | ||||
| 		numIndexTuples = 1.0; | ||||
| 	else | ||||
| 	{ | ||||
|  | ||||
| @ -7,7 +7,7 @@ | ||||
|  * Portions Copyright (c) 1996-2007, PostgreSQL Global Development Group | ||||
|  * Portions Copyright (c) 1994, Regents of the University of California | ||||
|  * | ||||
|  * $PostgreSQL: pgsql/src/include/access/skey.h,v 1.34 2007/01/05 22:19:51 momjian Exp $ | ||||
|  * $PostgreSQL: pgsql/src/include/access/skey.h,v 1.35 2007/04/06 22:33:42 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -52,6 +52,12 @@ typedef uint16 StrategyNumber; | ||||
|  * the operator.  When using a ScanKey in a heap scan, these fields are not | ||||
|  * used and may be set to InvalidStrategy/InvalidOid. | ||||
|  * | ||||
|  * A ScanKey can also represent a condition "column IS NULL"; this is signaled | ||||
|  * by the SK_SEARCHNULL flag bit.  In this case the argument is always NULL, | ||||
|  * and the sk_strategy, sk_subtype, and sk_func fields are not used (unless | ||||
|  * set by the index AM).  Currently, SK_SEARCHNULL is supported only for | ||||
|  * index scans, not heap scans; and not all index AMs support it. | ||||
|  * | ||||
|  * Note: in some places, ScanKeys are used as a convenient representation | ||||
|  * for the invocation of an access method support procedure.  In this case | ||||
|  * sk_strategy/sk_subtype are not meaningful, and sk_func may refer to a | ||||
| @ -111,6 +117,7 @@ typedef ScanKeyData *ScanKey; | ||||
| #define SK_ROW_HEADER	0x0004	/* row comparison header (see above) */ | ||||
| #define SK_ROW_MEMBER	0x0008	/* row comparison member (see above) */ | ||||
| #define SK_ROW_END		0x0010	/* last row comparison member (see above) */ | ||||
| #define SK_SEARCHNULL	0x0020	/* scankey represents a "col IS NULL" qual */ | ||||
| 
 | ||||
| 
 | ||||
| /*
 | ||||
|  | ||||
| @ -37,7 +37,7 @@ | ||||
|  * Portions Copyright (c) 1996-2007, PostgreSQL Global Development Group | ||||
|  * Portions Copyright (c) 1994, Regents of the University of California | ||||
|  * | ||||
|  * $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.400 2007/04/06 04:21:43 tgl Exp $ | ||||
|  * $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.401 2007/04/06 22:33:43 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -53,6 +53,6 @@ | ||||
|  */ | ||||
| 
 | ||||
| /*							yyyymmddN */ | ||||
| #define CATALOG_VERSION_NO	200704051 | ||||
| #define CATALOG_VERSION_NO	200704061 | ||||
| 
 | ||||
| #endif | ||||
|  | ||||
| @ -8,7 +8,7 @@ | ||||
|  * Portions Copyright (c) 1996-2007, PostgreSQL Global Development Group | ||||
|  * Portions Copyright (c) 1994, Regents of the University of California | ||||
|  * | ||||
|  * $PostgreSQL: pgsql/src/include/catalog/pg_am.h,v 1.50 2007/01/20 23:13:01 tgl Exp $ | ||||
|  * $PostgreSQL: pgsql/src/include/catalog/pg_am.h,v 1.51 2007/04/06 22:33:43 tgl Exp $ | ||||
|  * | ||||
|  * NOTES | ||||
|  *		the genbki.sh script reads this file and generates .bki | ||||
| @ -50,6 +50,7 @@ CATALOG(pg_am,2601) | ||||
| 	bool		amcanmulticol;	/* does AM support multi-column indexes? */ | ||||
| 	bool		amoptionalkey;	/* can query omit key for the first column? */ | ||||
| 	bool		amindexnulls;	/* does AM support NULL index entries? */ | ||||
| 	bool		amsearchnulls;	/* can AM search for NULL index entries? */ | ||||
| 	bool		amstorage;		/* can storage type differ from column type? */ | ||||
| 	bool		amclusterable;	/* does AM support cluster command? */ | ||||
| 	regproc		aminsert;		/* "insert this tuple" function */ | ||||
| @ -78,7 +79,7 @@ typedef FormData_pg_am *Form_pg_am; | ||||
|  *		compiler constants for pg_am | ||||
|  * ---------------- | ||||
|  */ | ||||
| #define Natts_pg_am						23 | ||||
| #define Natts_pg_am						24 | ||||
| #define Anum_pg_am_amname				1 | ||||
| #define Anum_pg_am_amstrategies			2 | ||||
| #define Anum_pg_am_amsupport			3 | ||||
| @ -87,37 +88,38 @@ typedef FormData_pg_am *Form_pg_am; | ||||
| #define Anum_pg_am_amcanmulticol		6 | ||||
| #define Anum_pg_am_amoptionalkey		7 | ||||
| #define Anum_pg_am_amindexnulls			8 | ||||
| #define Anum_pg_am_amstorage			9 | ||||
| #define Anum_pg_am_amclusterable		10 | ||||
| #define Anum_pg_am_aminsert				11 | ||||
| #define Anum_pg_am_ambeginscan			12 | ||||
| #define Anum_pg_am_amgettuple			13 | ||||
| #define Anum_pg_am_amgetmulti			14 | ||||
| #define Anum_pg_am_amrescan				15 | ||||
| #define Anum_pg_am_amendscan			16 | ||||
| #define Anum_pg_am_ammarkpos			17 | ||||
| #define Anum_pg_am_amrestrpos			18 | ||||
| #define Anum_pg_am_ambuild				19 | ||||
| #define Anum_pg_am_ambulkdelete			20 | ||||
| #define Anum_pg_am_amvacuumcleanup		21 | ||||
| #define Anum_pg_am_amcostestimate		22 | ||||
| #define Anum_pg_am_amoptions			23 | ||||
| #define Anum_pg_am_amsearchnulls		9 | ||||
| #define Anum_pg_am_amstorage			10 | ||||
| #define Anum_pg_am_amclusterable		11 | ||||
| #define Anum_pg_am_aminsert				12 | ||||
| #define Anum_pg_am_ambeginscan			13 | ||||
| #define Anum_pg_am_amgettuple			14 | ||||
| #define Anum_pg_am_amgetmulti			15 | ||||
| #define Anum_pg_am_amrescan				16 | ||||
| #define Anum_pg_am_amendscan			17 | ||||
| #define Anum_pg_am_ammarkpos			18 | ||||
| #define Anum_pg_am_amrestrpos			19 | ||||
| #define Anum_pg_am_ambuild				20 | ||||
| #define Anum_pg_am_ambulkdelete			21 | ||||
| #define Anum_pg_am_amvacuumcleanup		22 | ||||
| #define Anum_pg_am_amcostestimate		23 | ||||
| #define Anum_pg_am_amoptions			24 | ||||
| 
 | ||||
| /* ----------------
 | ||||
|  *		initial contents of pg_am | ||||
|  * ---------------- | ||||
|  */ | ||||
| 
 | ||||
| DATA(insert OID = 403 (  btree	5 1 t t t t t f t btinsert btbeginscan btgettuple btgetmulti btrescan btendscan btmarkpos btrestrpos btbuild btbulkdelete btvacuumcleanup btcostestimate btoptions )); | ||||
| DATA(insert OID = 403 (  btree	5 1 t t t t t t f t btinsert btbeginscan btgettuple btgetmulti btrescan btendscan btmarkpos btrestrpos btbuild btbulkdelete btvacuumcleanup btcostestimate btoptions )); | ||||
| DESCR("b-tree index access method"); | ||||
| #define BTREE_AM_OID 403 | ||||
| DATA(insert OID = 405 (  hash	1 1 f f f f f f f hashinsert hashbeginscan hashgettuple hashgetmulti hashrescan hashendscan hashmarkpos hashrestrpos hashbuild hashbulkdelete hashvacuumcleanup hashcostestimate hashoptions )); | ||||
| DATA(insert OID = 405 (  hash	1 1 f f f f f f f f hashinsert hashbeginscan hashgettuple hashgetmulti hashrescan hashendscan hashmarkpos hashrestrpos hashbuild hashbulkdelete hashvacuumcleanup hashcostestimate hashoptions )); | ||||
| DESCR("hash index access method"); | ||||
| #define HASH_AM_OID 405 | ||||
| DATA(insert OID = 783 (  gist	0 7 f f t t t t t gistinsert gistbeginscan gistgettuple gistgetmulti gistrescan gistendscan gistmarkpos gistrestrpos gistbuild gistbulkdelete gistvacuumcleanup gistcostestimate gistoptions )); | ||||
| DATA(insert OID = 783 (  gist	0 7 f f t t t t t t gistinsert gistbeginscan gistgettuple gistgetmulti gistrescan gistendscan gistmarkpos gistrestrpos gistbuild gistbulkdelete gistvacuumcleanup gistcostestimate gistoptions )); | ||||
| DESCR("GiST index access method"); | ||||
| #define GIST_AM_OID 783 | ||||
| DATA(insert OID = 2742 (  gin	0 4 f f f f f t f gininsert ginbeginscan gingettuple gingetmulti ginrescan ginendscan ginmarkpos ginrestrpos ginbuild ginbulkdelete ginvacuumcleanup gincostestimate ginoptions )); | ||||
| DATA(insert OID = 2742 (  gin	0 4 f f f f f f t f gininsert ginbeginscan gingettuple gingetmulti ginrescan ginendscan ginmarkpos ginrestrpos ginbuild ginbulkdelete ginvacuumcleanup gincostestimate ginoptions )); | ||||
| DESCR("GIN index access method"); | ||||
| #define GIN_AM_OID 2742 | ||||
| 
 | ||||
|  | ||||
| @ -7,7 +7,7 @@ | ||||
|  * Portions Copyright (c) 1996-2007, PostgreSQL Global Development Group | ||||
|  * Portions Copyright (c) 1994, Regents of the University of California | ||||
|  * | ||||
|  * $PostgreSQL: pgsql/src/include/nodes/relation.h,v 1.139 2007/02/27 01:11:26 tgl Exp $ | ||||
|  * $PostgreSQL: pgsql/src/include/nodes/relation.h,v 1.140 2007/04/06 22:33:43 tgl Exp $ | ||||
|  * | ||||
|  *------------------------------------------------------------------------- | ||||
|  */ | ||||
| @ -397,6 +397,7 @@ typedef struct IndexOptInfo | ||||
| 	bool		predOK;			/* true if predicate matches query */ | ||||
| 	bool		unique;			/* true if a unique index */ | ||||
| 	bool		amoptionalkey;	/* can query omit key for the first column? */ | ||||
| 	bool		amsearchnulls;	/* can AM search for NULL index entries? */ | ||||
| } IndexOptInfo; | ||||
| 
 | ||||
| 
 | ||||
|  | ||||
| @ -75,6 +75,12 @@ SELECT count(*) FROM fast_emp4000 WHERE home_base && '(1000,1000,0,0)'::box; | ||||
|      2 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT count(*) FROM fast_emp4000 WHERE home_base IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|    278 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT * FROM polygon_tbl WHERE f1 ~ '((1,1),(2,2),(2,1))'::polygon | ||||
|     ORDER BY (poly_center(f1))[0]; | ||||
|          f1           | ||||
| @ -125,6 +131,12 @@ SELECT count(*) FROM fast_emp4000 WHERE home_base && '(1000,1000,0,0)'::box; | ||||
|      2 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT count(*) FROM fast_emp4000 WHERE home_base IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|    278 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT * FROM polygon_tbl WHERE f1 ~ '((1,1),(2,2),(2,1))'::polygon | ||||
|     ORDER BY (poly_center(f1))[0]; | ||||
|          f1           | ||||
| @ -410,3 +422,71 @@ Indexes: | ||||
|     "std_index" btree (f2) | ||||
| 
 | ||||
| DROP TABLE concur_heap; | ||||
| -- | ||||
| -- Tests for IS NULL with b-tree indexes | ||||
| -- | ||||
| SELECT unique1, unique2 INTO onek_with_null FROM onek; | ||||
| INSERT INTO onek_with_null (unique1,unique2) VALUES (NULL, -1), (NULL, NULL); | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2,unique1); | ||||
| SET enable_seqscan = OFF; | ||||
| SET enable_indexscan = ON; | ||||
| SET enable_bitmapscan = ON; | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      2 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      1 | ||||
| (1 row) | ||||
| 
 | ||||
| DROP INDEX onek_nulltest; | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2 desc,unique1); | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      2 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      1 | ||||
| (1 row) | ||||
| 
 | ||||
| DROP INDEX onek_nulltest; | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2 desc nulls last,unique1); | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      2 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      1 | ||||
| (1 row) | ||||
| 
 | ||||
| DROP INDEX onek_nulltest; | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2  nulls first,unique1); | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      2 | ||||
| (1 row) | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
|  count  | ||||
| ------- | ||||
|      1 | ||||
| (1 row) | ||||
| 
 | ||||
| RESET enable_seqscan; | ||||
| RESET enable_indexscan; | ||||
| RESET enable_bitmapscan; | ||||
|   | ||||
| DROP TABLE onek_with_null; | ||||
|  | ||||
| @ -96,6 +96,8 @@ SELECT * FROM fast_emp4000 | ||||
| 
 | ||||
| SELECT count(*) FROM fast_emp4000 WHERE home_base && '(1000,1000,0,0)'::box; | ||||
| 
 | ||||
| SELECT count(*) FROM fast_emp4000 WHERE home_base IS NULL; | ||||
| 
 | ||||
| SELECT * FROM polygon_tbl WHERE f1 ~ '((1,1),(2,2),(2,1))'::polygon | ||||
|     ORDER BY (poly_center(f1))[0]; | ||||
| 
 | ||||
| @ -119,6 +121,8 @@ SELECT * FROM fast_emp4000 | ||||
| 
 | ||||
| SELECT count(*) FROM fast_emp4000 WHERE home_base && '(1000,1000,0,0)'::box; | ||||
| 
 | ||||
| SELECT count(*) FROM fast_emp4000 WHERE home_base IS NULL; | ||||
| 
 | ||||
| SELECT * FROM polygon_tbl WHERE f1 ~ '((1,1),(2,2),(2,1))'::polygon | ||||
|     ORDER BY (poly_center(f1))[0]; | ||||
| 
 | ||||
| @ -259,3 +263,45 @@ COMMIT; | ||||
| \d concur_heap | ||||
| 
 | ||||
| DROP TABLE concur_heap; | ||||
| 
 | ||||
| -- | ||||
| -- Tests for IS NULL with b-tree indexes | ||||
| -- | ||||
| 
 | ||||
| SELECT unique1, unique2 INTO onek_with_null FROM onek; | ||||
| INSERT INTO onek_with_null (unique1,unique2) VALUES (NULL, -1), (NULL, NULL); | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2,unique1); | ||||
| 
 | ||||
| SET enable_seqscan = OFF; | ||||
| SET enable_indexscan = ON; | ||||
| SET enable_bitmapscan = ON; | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
| 
 | ||||
| DROP INDEX onek_nulltest; | ||||
| 
 | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2 desc,unique1); | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
| 
 | ||||
| DROP INDEX onek_nulltest; | ||||
| 
 | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2 desc nulls last,unique1); | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
| 
 | ||||
| DROP INDEX onek_nulltest; | ||||
| 
 | ||||
| CREATE UNIQUE INDEX onek_nulltest ON onek_with_null (unique2  nulls first,unique1); | ||||
| 
 | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL; | ||||
| SELECT count(*) FROM onek_with_null WHERE unique1 IS NULL AND unique2 IS NULL; | ||||
| 
 | ||||
| RESET enable_seqscan; | ||||
| RESET enable_indexscan; | ||||
| RESET enable_bitmapscan; | ||||
|   | ||||
| DROP TABLE onek_with_null; | ||||
|  | ||||
		Loading…
	
	
			
			x
			
			
		
	
		Reference in New Issue
	
	Block a user