B-Tree Indexes index B-Tree Introduction PostgreSQL includes an implementation of the standard btree (multi-way binary tree) index data structure. Any data type that can be sorted into a well-defined linear order can be indexed by a btree index. The only limitation is that an index entry cannot exceed approximately one-third of a page (after TOAST compression, if applicable). Because each btree operator class imposes a sort order on its data type, btree operator classes (or, really, operator families) have come to be used as PostgreSQL's general representation and understanding of sorting semantics. Therefore, they've acquired some features that go beyond what would be needed just to support btree indexes, and parts of the system that are quite distant from the btree AM make use of them. Behavior of B-Tree Operator Classes As shown in , a btree operator class must provide five comparison operators, <, <=, =, >= and >. One might expect that <> should also be part of the operator class, but it is not, because it would almost never be useful to use a <> WHERE clause in an index search. (For some purposes, the planner treats <> as associated with a btree operator class; but it finds that operator via the = operator's negator link, rather than from pg_amop.) When several data types share near-identical sorting semantics, their operator classes can be grouped into an operator family. Doing so is advantageous because it allows the planner to make deductions about cross-type comparisons. Each operator class within the family should contain the single-type operators (and associated support functions) for its input data type, while cross-type comparison operators and support functions are loose in the family. It is recommendable that a complete set of cross-type operators be included in the family, thus ensuring that the planner can represent any comparison conditions that it deduces from transitivity. There are some basic assumptions that a btree operator family must satisfy: An = operator must be an equivalence relation; that is, for all non-null values A, B, C of the data type: A = A is true (reflexive law) if A = B, then B = A (symmetric law) if A = B and B = C, then A = C (transitive law) A < operator must be a strong ordering relation; that is, for all non-null values A, B, C: A < A is false (irreflexive law) if A < B and B < C, then A < C (transitive law) Furthermore, the ordering is total; that is, for all non-null values A, B: exactly one of A < B, A = B, and B < A is true (trichotomy law) (The trichotomy law justifies the definition of the comparison support function, of course.) The other three operators are defined in terms of = and < in the obvious way, and must act consistently with them. For an operator family supporting multiple data types, the above laws must hold when A, B, C are taken from any data types in the family. The transitive laws are the trickiest to ensure, as in cross-type situations they represent statements that the behaviors of two or three different operators are consistent. As an example, it would not work to put float8 and numeric into the same operator family, at least not with the current semantics that numeric values are converted to float8 for comparison to a float8. Because of the limited accuracy of float8, this means there are distinct numeric values that will compare equal to the same float8 value, and thus the transitive law would fail. Another requirement for a multiple-data-type family is that any implicit or binary-coercion casts that are defined between data types included in the operator family must not change the associated sort ordering. It should be fairly clear why a btree index requires these laws to hold within a single data type: without them there is no ordering to arrange the keys with. Also, index searches using a comparison key of a different data type require comparisons to behave sanely across two data types. The extensions to three or more data types within a family are not strictly required by the btree index mechanism itself, but the planner relies on them for optimization purposes. B-Tree Support Functions As shown in , btree defines one required and two optional support functions. For each combination of data types that a btree operator family provides comparison operators for, it must provide a comparison support function, registered in pg_amproc with support function number 1 and amproclefttype/amprocrighttype equal to the left and right data types for the comparison (i.e., the same data types that the matching operators are registered with in pg_amop). The comparison function must take two non-null values A and B and return an int32 value that is < 0, 0, or > 0 when A < B, A = B, or A > B, respectively. The function must not return INT_MIN for the A < B case, since the value may be negated before being tested for sign. A null result is disallowed, too. See src/backend/access/nbtree/nbtcompare.c for examples. If the compared values are of a collatable data type, the appropriate collation OID will be passed to the comparison support function, using the standard PG_GET_COLLATION() mechanism. Optionally, a btree operator family may provide sort support function(s), registered under support function number 2. These functions allow implementing comparisons for sorting purposes in a more efficient way than naively calling the comparison support function. The APIs involved in this are defined in src/include/utils/sortsupport.h. in_range support functions support functions in_range Optionally, a btree operator family may provide in_range support function(s), registered under support function number 3. These are not used during btree index operations; rather, they extend the semantics of the operator family so that it can support window clauses containing the RANGE offset PRECEDING and RANGE offset FOLLOWING frame bound types (see ). Fundamentally, the extra information provided is how to add or subtract an offset value in a way that is compatible with the family's data ordering. An in_range function must have the signature in_range(val type1, base type1, offset type2, sub bool, less bool) returns bool val and base must be of the same type, which is one of the types supported by the operator family (i.e., a type for which it provides an ordering). However, offset could be of a different type, which might be one otherwise unsupported by the family. An example is that the built-in time_ops family provides an in_range function that has offset of type interval. A family can provide in_range functions for any of its supported types and one or more offset types. Each in_range function should be entered in pg_amproc with amproclefttype equal to type1 and amprocrighttype equal to type2. The essential semantics of an in_range function depend on the two boolean flag parameters. It should add or subtract base and offset, then compare val to the result, as follows: if !sub and !less, return val >= (base + offset) if !sub and less, return val <= (base + offset) if sub and !less, return val >= (base - offset) if sub and less, return val <= (base - offset) Before doing so, the function should check the sign of offset: if it is less than zero, raise error ERRCODE_INVALID_PRECEDING_OR_FOLLOWING_SIZE (22013) with error text like invalid preceding or following size in window function. (This is required by the SQL standard, although nonstandard operator families might perhaps choose to ignore this restriction, since there seems to be little semantic necessity for it.) This requirement is delegated to the in_range function so that the core code needn't understand what less than zero means for a particular data type. An additional expectation is that in_range functions should, if practical, avoid throwing an error if base + offset or base - offset would overflow. The correct comparison result can be determined even if that value would be out of the data type's range. Note that if the data type includes concepts such as infinity or NaN, extra care may be needed to ensure that in_range's results agree with the normal sort order of the operator family. The results of the in_range function must be consistent with the sort ordering imposed by the operator family. To be precise, given any fixed values of offset and sub, then: If in_range with less = true is true for some val1 and base, it must be true for every val2 <= val1 with the same base. If in_range with less = true is false for some val1 and base, it must be false for every val2 >= val1 with the same base. If in_range with less = true is true for some val and base1, it must be true for every base2 >= base1 with the same val. If in_range with less = true is false for some val and base1, it must be false for every base2 <= base1 with the same val. Analogous statements with inverted conditions hold when less = false. If the type being ordered (type1) is collatable, the appropriate collation OID will be passed to the in_range function, using the standard PG_GET_COLLATION() mechanism. in_range functions need not handle NULL inputs, and typically will be marked strict. Implementation An introduction to the btree index implementation can be found in src/backend/access/nbtree/README.