Experimental Thoughts » Temporal http://thoughts.davisjeff.com Ideas on Databases, Logic, and Language by Jeff Davis Sat, 16 Jun 2012 21:05:47 +0000 en hourly 1 http://wordpress.org/?v=3.3.1 Exclusion Constraints are generalized SQL UNIQUE http://thoughts.davisjeff.com/2010/09/25/exclusion-constraints-are-generalized-sql-unique/ http://thoughts.davisjeff.com/2010/09/25/exclusion-constraints-are-generalized-sql-unique/#comments Sat, 25 Sep 2010 20:37:22 +0000 Jeff Davis http://thoughts.davisjeff.com/?p=321 Continue reading ]]> Say you are writing an online reservation system. The first requirement you’ll encounter is that no two reservations may overlap (i.e. no schedule conflicts). But how do you prevent that?

It’s worth thinking about your solution carefully. My claim is that no existing SQL DBMS has a good solution to this problem before PostgreSQL 9.0, which has just been released. This new release includes a feature called Exclusion Constraints (authored by me), which offers a good solution to a class of problems that includes the “schedule conflict” problem.

I previously wrote a two part series (Part 1 and Part 2) on this topic. Chances are that you’ve run into a problem similar to this at one time or another, and these articles will show you the various solutions that people usually employ in the real world, and the serious problems and limitations of those approaches.

The rest of this article will be a brief introduction to Exclusion Constraints to get you started using a much better approach.

First, install PostgreSQL 9.0 (the installation instructions are outside the scope of this article), and launch psql.

Then, install two modules: “temporal” (which provides the PERIOD data type and associated operators) and “btree_gist” (which provides btree functionality via GiST).

Before installing these modules, make sure that PostgreSQL 9.0 is installed and that the 9.0 pg_config is in your PATH environment variable. Also, $SHAREDIR meas the directory listed when you run pg_config --sharedir.

To install Temporal PostgreSQL:

  1. download the tarball
  2. unpack the tarball, go into the directory, and type “make install
  3. In psql, type: \i $SHAREDIR/contrib/period.sql

To install BTree GiST (these directions assume you installed from source, some packages may help here, like Ubuntu’s “postgresql-contrib” package):

  1. Go to the postgresql source “contrib” directory, go to btree_gist, and type “make install“.
  2. In psql, type: \i $SHAREDIR/contrib/btree_gist.sql

Now that you have those modules installed, let’s start off with some basic Exclusion Constraints:

DROP TABLE IF EXISTS a;
CREATE TABLE a(i int);
ALTER TABLE a ADD EXCLUDE (i WITH =);

That is identical to a UNIQUE constraint on a.i, except that it uses the Exclusion Constraints mechanism; it even uses a normal BTree to enforce it. The performance will be slightly worse because of some micro-optimizations for UNIQUE constraint, but only slightly, and the performance characteristics should be the same (it’s just as scalable). Most importantly, it behaves the same under high concurrency as a UNIQUE constraint, so you don’t have to worry about excessive locking. If one person inserts 5, that will prevent other transactions from inserting 5 concurrently, but will not interfere with a transaction inserting 6.

Let’s take apart the syntax a little. The normal BTree is the default, so that’s omitted. The (i WITH =) is the interesting part, of course. It means that one tuple TUP1 conflicts with another tuple TUP2 if TUP1.i = TUP2.i. No two tuples may exist in the table if they conflict. In other words, there are no two tuples TUP1 and TUP2 in the table, such that TUP1.i = TUP2.i. That’s the very definition of UNIQUE, so that shows the equivalence. NULLs are always permitted, just like with UNIQUE constraints.

Now, let’s see if they hold up for multi-column constraints:

DROP TABLE IF EXISTS a;
CREATE TABLE a(i int, j int);
ALTER TABLE a ADD EXCLUDE (i WITH =, j WITH =);

The conditions for a conflicting tuple are ANDed together, just like UNIQUE. So now, in order for two tuples to conflict, TUP1.i = TUP2.i AND TUP1.j = TUP2.j. This is strictly a more permissive constraint, because conflicts require both conditions to be met. Therefore, this is identical to a UNIQUE constraint on (a.i, a.j).

What can we do that UNIQUE can’t? Well, for starters we can use something other than a normal BTree, such as Hash or GiST (for the moment, GIN is not supported, but that’s only because GIN doesn’t support the full index AM API; amgettuple in particular):

DROP TABLE IF EXISTS a;
CREATE TABLE a(i int, j int);
ALTER TABLE a ADD EXCLUDE USING gist (i WITH =, j WITH =);
-- alternatively using hash, which doesn't support
-- multi-column indexes at all
ALTER TABLE a ADD EXCLUDE USING hash (i WITH =);

So now we can do UNIQUE constraints using hash or gist. But that’s not a real benefit, because a normal btree is probably the most efficient way to support that, anyway (Hash may be in the future, but for the moment it doesn’t use WAL, which is a major disadvantage).

The difference really comes from the ability to change the operator to something other than “=“. It can be any operator that is:

  • Commutative
  • Boolean
  • Searchable by the given index access method (e.g. btree, hash, gist).

For BTree and Hash, the only operator that meets those criteria is “=”. But many data types (including PERIOD, CIRCLE, BOX, etc.) support lots of interesting operators that are searchable using GiST. For instance, “overlaps” (&&).

Ok, now we are getting somewhere. It’s impossible to specify the constraint that no two tuples contain values that overlap with eachother using a UNIQUE constraint; but it is possible to specify such a constraint with an Exclusion Constraint! Let’s try it out.

DROP TABLE IF EXISTS b;
CREATE TABLE b (p PERIOD);
ALTER TABLE b ADD EXCLUDE USING gist (p WITH &&);
INSERT INTO b VALUES('[2009-01-05, 2009-01-10)');
INSERT INTO b VALUES('[2009-01-07, 2009-01-12)'); -- causes ERROR

Now, try out various combinations (including COMMITs and ABORTs), and try with concurrent sessions also trying to insert values. You’ll notice that potential conflicts cause transactions to wait on eachother (like with UNIQUE) but non-conflicting transactions proceed unhindered. A lot better than LOCK TABLE, to say the least.

To be useful in a real situation, let’s make sure that the semantics extend nicely to a more complete problem. In reality, you generally have several exclusive resources in play, such as people, rooms, and time. But out of those, “overlaps” really only makes sense for time (in most situations). So we need to mix these concepts a little.

CREATE TABLE reservation(room TEXT, professor TEXT, during PERIOD);

-- enforce the constraint that the room is not double-booked
ALTER TABLE reservation
    ADD EXCLUDE USING gist
    (room WITH =, during WITH &&);

-- enforce the constraint that the professor is not double-booked
ALTER TABLE reservation
    ADD EXCLUDE USING gist
   (professor WITH =, during WITH &&);

Notice that we actually need to enforce two constraints, which is expected because there are two time-exclusive resources: professors and rooms. Multiple constraints on a table are ORed together, in the sense that an ERROR occurs if any constraint is violated. For the academic readers out there, this means that exclusion constraint conflicts are specified in disjunctive normal form (consistent with UNIQUE constraints).

The semantics of Exclusion Constraints extend in a clean way to support this mix of atomic resources (rooms, people) and resource ranges (time). Try it out, again with a mix of concurrency, commits, aborts, conflicting and non-conflicting reservations.

Exclusion constraints allow solving this class of problems quickly (in a couple lines of SQL) in a way that’s safe, robust, generally useful across many applications in many situations, and with higher performance and better scalability than other solutions.

Additionally, Exclusion Constraints support all of the advanced features you’d expect from a system like Postgres9: deferrability, applying the constraint to only a subset of the table (allows a WHERE clause), or using functions/expressions in place of column references.

]]>
http://thoughts.davisjeff.com/2010/09/25/exclusion-constraints-are-generalized-sql-unique/feed/ 9
Temporal PostgreSQL Roadmap http://thoughts.davisjeff.com/2010/03/09/temporal-postgresql-roadmap/ http://thoughts.davisjeff.com/2010/03/09/temporal-postgresql-roadmap/#comments Wed, 10 Mar 2010 04:49:06 +0000 Jeff Davis http://thoughts.davisjeff.com/?p=254 Continue reading ]]> Why are temporal extensions in PostgreSQL important? Quite simply, managing time data is one of the most common requirements, and current general-purpose database systems don’t provide us with the basic tools to do it. Every general-purpose DBMS falls short both in terms of usability and performance when trying to manage temporal data.

What is already done?

  • PERIOD data type, which can represent anchored intervals of time; that is, a chunk of time with a definite beginning and a definite end (in contrast to a SQL INTERVAL, which is not anchored to any specific beginning or end time).
    • Critical for usability because it acts as a set of time, so you can easily test for containment and other operations without using awkward constructs like BETWEEN or lots of comparisons (and keeping track of inclusivity/exclusivity of boundary points).
    • Critical for performance because you can index the values for efficient “contains” and “overlaps” queries (among others).
  • Temporal Keys (called Exclusion Constraints, and will be available in the next release of PostgreSQL, 9.0), which can enforce the constraint that no two periods of time (usually for a given resource, like a person) overlap. See the documentation (look for the word “EXCLUDE”), and see my previous articles (part 1 and part 2) on the subject.
    • Critical for usability to avoid procedural, error-prone hacks to enforce the constraint with triggers or by splitting time into big chunks.
    • Critical for performance because it performs comparably to a UNIQUE index, unlike the other procedural hacks which are generally too slow to use for most real systems.

What needs to be done?

  • Range Types — Aside from PERIOD, which is based on TIMESTAMPTZ, it would also be useful to have very similar types based on, for example, DATE. It doesn’t stop there, so the natural conclusion is to generalize PERIOD into “range types” which could be based on almost any subtype.
  • Range Keys, Foreign Range Keys — If Range Types are known to the Postgres engine, that means that we can have syntactic sugar for range keys (like temporal keys, except for any range type), etc., that would internally use Exclusion Constraints.
  • Range Join — If Range Types are known to the Postgres engine, there could be syntactic sugar for a “range join,” that is, a join based on “overlaps” rather than “equals”. More importantly, there could be a new join type, a Range Merge Join, that could perform this join efficiently (without a Range Merge Join, a range join would always be a nested loop join).
  • Simple table logs — The ability to easily create an effective “audit log” or similar trigger-based table log, that can record changes and be efficiently queried for historical state or state changes.

I’ll be speaking on this subject (specifically, the new Exclusion Constraints feature) in the upcoming PostgreSQL Conference EAST 2010 (my talk description) in Philadelphia later this month and PGCon 2010 (my talk description) in Ottawa this May. In the past, these conferences and others have been a great place to get ideas and help me move the temporal features forward.

The existing features have been picking up a little steam lately. The temporal-general mailing list has some traffic now — fairly low, but enough that others contribute to the discussions, which is a great start. I’ve also received some great feedback from a number of people, including the folks at PGX. There’s still a ways to go before we have all the features we want, but progress is being made.

]]>
http://thoughts.davisjeff.com/2010/03/09/temporal-postgresql-roadmap/feed/ 8
Temporal Keys, Part 2 http://thoughts.davisjeff.com/2009/11/08/temporal-keys-part-2/ http://thoughts.davisjeff.com/2009/11/08/temporal-keys-part-2/#comments Mon, 09 Nov 2009 05:48:37 +0000 Jeff Davis http://thoughts.davisjeff.com/?p=180 Continue reading ]]> In the last article, I argued that:

  • A schedule conflict is a typical business problem.
  • The later you try to resolve a schedule conflict, the more costly it is to resolve.
  • In particular, there is a big jump in the cost the moment after conflicting data is recorded.
  • Therefore, it’s best for the DBMS itself to enforce the constraint, because only the DBMS can avoid the conflict effectively before the conflict is recorded.

Then, I opened up a discussion to see how people are dealing with these schedule conflicts. In the comments I received at the end of the article, as well as other anecdotes from conferences, user groups, mailing lists, and my own experience, the solutions fall into a few categories:

  • The rate of conflicts is so low that the costs are not important. For instance, you may make 0.1% of your customers unhappy, and need to refund them, but perhaps that’s a cost you’re willing to pay.
  • The application receives so few requests that performance is not an object, and serialization of all requests is a viable option. The serialization is done using big locks and a read-check-write cycle. Even if performance is not an object, these applications sometimes run into maintenance problems or unexpected outages because of the big locks required.
  • You can break the time slices into manageable chunks, e.g. one day chunks aligned at midnight. This kind of solution is highly specific to the business, reduces the flexibility of the business, and often requires a substantial amount of custom, error-prone procedural code.
  • Complex procedural code: usually a mix of application code, functions in the DBMS, row-level locking, static data in tables that only exists for the purposes of row-level locks, etc. This kind of solution is generally very specific to the application and the business, requires lots of very error-prone custom procedural code, is difficult to adequately test, and it’s hard to understand what’s going on in the system at any given time. Hunting down sporadic performance problems would be a nightmare.

Those solutions just aren’t good enough. We use relational database systems because they are smart, declarative, generally useful for many problems, and maintainable (Note: these principles contrast with NoSQL, which is moving in the opposite direction — more on that in another article).

[UPDATE: The following project has been committed for the next release of PostgreSQL; the feature is now called "Exclusion Constraints"; and the new version of PostgreSQL will be called 9.0 (not 8.5). See the documentation under the heading "EXCLUDE".]

The project that I’ve been working on for PostgreSQL 8.5 is called “Operator Exclusion Constraints“. These are a new type of constraint that most closely resembles the UNIQUE constraint, because one tuple can preclude the existence of other tuples. With a UNIQUE constraint on attribute A of a table with attributes (A, B, C), the existence of the tuple (5, 6, 7) precludes the existence of any tuple (5, _, _) in that table at the same time. This is different from a foreign key, which requires the existence of a tuple in another table; and different from a CHECK constraint which rejects tuples independently from any other tuple in any table (and the same goes for NOT NULL).

The same semantics as a UNIQUE constraint can be easily specified as an Operator Exclusion Constraint, with a minor performance penalty at insert time (one additional index search, usually only touching pages that are already in cache). Exclusion constraints are more general than UNIQUE, however. For instance, with a complex type such as CIRCLE, you can specify that no two circles in a table overlap — which is a constraint that is impossible to specify otherwise (without resorting to the poor solutions mentioned above).

This applies to temporal keys very nicely. First, get the PERIOD data type, which allows you a better way to work with periods of time (sets of time, really), rather than points in time. Second, you need to install the btree_gist contrib module. Then, use an exclusion constraint like so:

[UPDATE 2010-03-09: Syntax updated to reflect the version of this project committed for PostgreSQL 9.0. ]

CREATE TABLE room_reservation
(
  name   TEXT,
  room   TEXT,
  during PERIOD,
  EXCLUDE USING gist (room WITH =, during WITH &&)
);

That will prevent two reservations on the same room from overlapping. There are a few pieces to this that require explanation:

  • && is the “overlaps” operator for the PERIOD data type.
  • USING gist tells PostgreSQL what kind of index to create to enforce this constraint. The operators must map to search strategies for this index method, and searching for overlapping periods requires a GiST index.
  • Because we are using GiST, we need GiST support for equality searches for the TEXT data type, which is the reason we need the btree_gist contrib module.
  • Conflicts will only occur if two tuples have equal room numbers, and overlapping periods of time for the reservation.

This solution:

  • Performs well under light and heavy contention. Not quite as well as a UNIQUE constraint, but much better than the alternatives, and without the surprises you might get from using big locks. Note that the constraint will be enforced at some point, so ignoring the problem is not a high-performance alternative (interpersonal communication has higher latency than a computer).
  • Is declarative. The implementation shows through a little bit — the user will know that an index is being used, for instance — but it’s a relatively simple declaration. As a consequence, it’s not very error-prone from the schema designer’s standpoint.
  • Is not specific to the business. You don’t have to decide on an appropriate time slice (e.g. one hour, one day, etc.); you don’t have to try to partition locks in creative ways; you don’t have to write procedural code (in the database system or application); and you don’t have to come up with interesting ways to detect a conflict or notify the user.

Temporal keys are just one part of the support required for effective temporal data management inside the DBMS. However, it’s one of the most important pieces that requires support from the core engine, and cannot be implemented as a module.

]]>
http://thoughts.davisjeff.com/2009/11/08/temporal-keys-part-2/feed/ 11
Temporal Keys, Part 1 http://thoughts.davisjeff.com/2009/11/01/temporal-keys-part-1/ http://thoughts.davisjeff.com/2009/11/01/temporal-keys-part-1/#comments Mon, 02 Nov 2009 00:55:34 +0000 Jeff Davis http://thoughts.davisjeff.com/?p=171 Continue reading ]]> “Schedule conflict” — it’s one of the simplest and most common constraints for business or any other organization. One person cannot be in two places at the same time; and in many cases a only a single person can use a given resource at any time.

Does your database system know anything about a schedule conflict? Should it?

Constraints are always enforced at some point, it’s just a matter of when, how, and the cost of correcting the situation.

Consider two professors who try to reserve the same lecture hall at overlapping times (let’s say 1-2pm, and 1:30-2:30pm). Now imagine two possible resolutions:

  1. They are blissfully unaware of the schedule conflict until they have already promoted their lecture, attracted an audience, and arrived at the building. The professor scheduled for 1:30-2:30pm will be disappointed to find it already in use, and the students will be confused. The second lecture may have to be canceled due to the confusion, or lose a substantial number of attendees.
  2. At the time of scheduling, one professor is given an error message to the effect of “this room is already reserved, please choose a different time”.

Observe that neither one really solves the problem: the second resolution still forces one professor to choose a less-desirable time. However, it is a much cheaper resolution. As with many problems, early detection is simplest and cheapest to resolve.

Of course, there are many resolutions that fall between the first and the second. For instance, you might run a program every hour that checks for conflicts and alerts the parties involved. That may work, but there are still problems:

  • You’ve now introduced uncertainty into the system: do I have a reservation or not? If there is a conflict later, will I be kicked out or will they?
  • You have to come up with rules for resolution: does the first one win? How do you define “first” if transactions are running for a while? What if someone makes a reservation “first” but then makes all kinds of changes later; were they really first or did they just game the system?
  • If someone’s reservation gets bumped, you have to now have a new strange state for a reservation, in which it is disabled, the organizer has (hopefully) been notified, and it needs to change.
  • Notice that everything is very procedural and specific to the business. You have to have a notification mechanism, and rules for how to resolve it.
  • Let’s go back to the definition of “first”: say you have made a reservation, and you get bumped by the conflict detector. In between the time you made the reservation and the time you were notified of a conflict, someone else reserved your second choice. Are you now first in line for that time slot? If so, that has a cascading effect such that it’s almost impossible for the person that took the second-choice slot to know that they are at risk of being bumped.

These thought experiments might seem like edge cases, but reservation systems have two common traits that make these problems very real:

  1. They tend to start allowing reservations of a specific resource at a specific time, published in advance.
  2. There tend to be some resources and time slots that have a much higher value than the others.

These two traits lead to heavy contention.

Now, how would you go about enforcing such a constraint (non-overlapping time periods) in the database? While considering possible solutions, think about:

  • Does the solution work for a wide variety of use cases, or only in special cases?
  • How well would it perform, under low contention and high contention, and under varied workloads?
  • Can it be implemented in a general purpose RDBMS, like PostgreSQL?
  • Is it procedural in nature, or declarative?

I think it’s worthwhile to consider the problem, so I will end this article now, and provide some approaches, as well as my real answer, in the next article. In the meantime, feel free to post ideas as comments.

]]>
http://thoughts.davisjeff.com/2009/11/01/temporal-keys-part-1/feed/ 13
PostgreSQL WEST and Temporal Databases http://thoughts.davisjeff.com/2009/10/12/postgresql-west-and-temporal-databases/ http://thoughts.davisjeff.com/2009/10/12/postgresql-west-and-temporal-databases/#comments Tue, 13 Oct 2009 05:09:57 +0000 Jeff Davis http://thoughts.davisjeff.com/?p=152 Continue reading ]]> I’ve been interested in temporal data and relational databases for quite some time. There are going to be at least two people talking about temporal data at PostgreSQL WEST in Seattle: Scott Bailey and me. See the talk descriptions.

In the past, I’ve worked on a temporal extension to PostgreSQL that implements the PERIOD data type. This is a data type that offers both a definite beginning and a definite end time, which is important for describing things that happen over a period of time, rather than instantaneously. Trying to use separate attributes for “start” and “end” is bad for a number of reasons, and will certainly be addressed in a subsequent blog entry. For now, I’ll just say that I believe the PERIOD data type is fundamentally important for handling all kinds of time data, which I believe is a common problem.

At WEST, I’ll be presenting my progress on temporal keys. Temporal keys are used to prevent overlapping periods of time — a schedule conflict — by using an index and following the same concurrent behavior as UNIQUE with minimal performance cost (one extra index search, to be precise).

Temporal keys cannot be expressed in PostgreSQL 8.4, unless you resort to triggers and a full table lock (ouch!). So, additional backend support is required. This is accomplished in my patch for operator exclusion constraints, which are a more general way of using arbitrary operators and index searches to enforce a constraint. I plan to do what’s required for the patch to be accepted in PostgreSQL 8.5.

Temporal modeling is a common problem. It seems like almost every PostgreSQL conference has had at least one talk on the matter, so we know there is some demand for improvement. If you’re interested, I hope you come to WEST and chat with Scott or I, and let’s see if we can come up with some real solutions.

]]>
http://thoughts.davisjeff.com/2009/10/12/postgresql-west-and-temporal-databases/feed/ 5