Interval arithmetic [YSQL]

Interval arithmetic

This section uses the term "moment" as an umbrella for a timestamptz value, a timestamp value, or a time value. (In a broader scenario, a date value is also a moment. But you get an integer value when you subtract one date value from another. And you cannot add or subtract an interval value to/from a date value.) The term "interval arithmetic" is used somewhat loosely to denote these three distinct scenarios:

You need to understand the notions that the section Two ways of conceiving of time: calendar-time and clock-time addresses in order to understand the code and the explanations in this page's child page The moment-interval overloads of the "+" and "-" operators for timestamptz, timestamp, and time. The notions help you understand how the semantic rules of the native moment-moment overloads of the "-" operator for timestamptz, timestamp, and time are ultimately confusing and therefore unhelpful—and why you should therefore adopt the practices that the section Custom domain types for specializing the native interval functionality explains. The distinction between clock-time-semantics and calendar-time-semantics is only implicitly relevant for the notions that the sections The interval-interval overload of the "=" operator and Interval-only addition/subtraction and multiplication/division explain.

The PostgreSQL documentation does not carefully specify the semantics of interval arithmetic. This page and its children aim to specify the operations in terms of the individual fields of the internal representation.

The results of 'interval' arithmetic are, in general, sensitive to the session's timezone.

More carefully stated, the results of some moment-interval arithmetic operations (the moment-moment overloads of the - operator and the moment-interval overloads of the + and - operators) are sensitive to the session's TimeZone setting when the moments are timestamptz values.

The interval-interval overload of the "=" operator

Try this:

select
  (
    '5 days  1 hours'::interval =
    '4 days 25 hours'::interval
  )::text as "'1 day' is defined to be equal to '24 hours'",
  (
    '5 months  1 day' ::interval =
    '4 months 31 days'::interval
  )::text as "'1 month' is defined to be equal to '30 days'";

The result for each equality expression is true. This is a strange definition of equality because there are 29 days in February in a leap year and otherwise 28 days, there are four 30 day months, and there are seven 31 day months. Further, 1 day is only usually 24 hours. (The usually caveat acknowledges the consequences of Daylight Savings Time changes.) All this crucially effects the semantics—see interval-moment arithmetic below.

The section Comparing two interval values explains the model that the interval overload of the = operator uses and tests it with a PL/pgSQL implementation. It also shows how to implement a user-defined interval-interval == operator that implements strict equality. The criterion for this is that each field of the LHS and RHS [mm, dd, ss] internal representations must be pairwise equal.

Interval-only addition/subtraction and multiplication/division

Empirical tests show the following:

  • The + operator and the - operator are overloaded to allow the addition and subtraction of two interval values. Here, the outcome can be understood in terms of pairwise field-by-field addition or subtraction of the two [mm, dd, ss] tuples.

  • The * operator and the / operator are overloaded to allow multiplication or division of an interval value by a real or integer number. Here, the outcome can be mainly understood in terms of multiplying, or dividing, the [mm, dd, ss] tuple, field-by-field, using the same factor. Notice the caveat mainly. In some rare corner cases, the model holds only when the forgiving built-in interval-interval = operator is used to compare the outcome of the model with that of the actual functionality. When the user-defined strict equality interval-interval ==operator is used, the tests show that, in these corner cases, the outcome of the model does not agree with that of the actual functionality.

In all cases of addition/subtraction and multiplication/division, the model assumes that a new intermediate [mm, dd, ss] tuple is produced and that each of the mm or dd fields might well be real numbers. It must be assumed that this intermediate value is then coerced into the required [integer, integer, real number] format using the same algorithm (see the section Modeling the internal representation and comparing the model with the actual implementation) that is used when such a tuple is provided in the ::interval typecast approach.

The interval-interval overloads of the "+" and "-" operators

The operation acts separately on the three individual fields of the internal representation adding or subtracting them pairwise:

  • [mm1, dd1, ss1] ± [mm2, dd2, ss2] = [(mm1 ± mm2), (dd1 ± dd2), (ss1 ± ss2)]

The section Adding or subtracting a pair of interval values simulates and tests the model for how this works in PL/pgSQL code.

Try this simple test:

select '2 months'::interval + '2 days'::interval;

This is the result:

 2 mons 2 days

This is consistent with the assumed model. And it shows that a practice that the user might adopt to use only interval values that have just a single non-zero internal representation field can easily be thwarted by interval-interval addition or subtraction.

The interval-number overloads of the "*" and "/" operators

The operation is assumed to be intended to act separately on each of the three individual fields:

  • [mm, dd, ss]*x = [mm*x, dd*x, ss*x]

When x is equal to f, where f > 1, the effect is multiplication by f. And when x is equal to 1/f, where f > 1, the effect is division by f. Therefore a single mental model explains both operations.

Try this positive test:

select
  '2 months 2 days'::interval*0.9                    as "result 1",
  '2 months'::interval*0.9 + '2 days'::interval*0.9  as "result 2";

This is the result:

        result 1        |        result 2
------------------------+------------------------
 1 mon 25 days 19:12:00 | 1 mon 25 days 19:12:00

It is consistent with the assumed model.

Now try this negative test:

select
  '2 months 2 days'::interval*0.97                     as "result 1",
  '2 months'::interval*0.97 + '2 days'::interval*0.97  as "result 1";

This is the result:

        result 1        |        result 1
------------------------+------------------------
 1 mon 30 days 03:21:36 | 1 mon 29 days 27:21:36

It is not consistent with the assumed model. But the only difference between the positive test and the negative test is that the former uses the factor 0.9 and the latter uses the factor 0.97.

Compare the apparently different results using the forgiving native interval-interval '=' operator like this:

select ('1 mon 30 days 03:21:36'::interval = '1 mon 29 days 27:21:36'::interval)::text;

The result is true. The section Multiplying or dividing an interval value by a number simulates and tests the model for how this works in PL/pgSQL code, and examines this unexpected outcome closely.

One thing, at least, is clear: a practice that the user might adopt to use only interval values that have just a single non-zero internal representation field can easily be thwarted by interval-number multiplication or division. Moreover, the semantics of these operations is not documented and cannot be reliably determined by empirical investigation. The outcomes must, therefore, be considered to be unpredictable.

Recommendation

Avoid native 'interval'-'interval' addition/subtraction and 'interval'-number multiplication/division.

Yugabyte recommends that you avoid performing operations whose results can easily thwart an adopted principle for good practice and especially that you avoid operations whose outcomes must be considered to be unpredictable. It recommends that instead you adopt the practice that the section Defining and using custom domain types to specialize the native interval functionality explains. Doing this will let you perform the addition, subtraction, multiplication, and division operations that are unsafe with native interval values in a controlled fashion that brings safety.

Moment-interval arithmetic

The - operator has a set of moment-moment overloads and a set of moment-interval overloads. The + operator has a set of -interval-moment overloads. The + operator has no moment-moment overloads. (This operation would make no sense.)

The moment-moment overloads of the "-" operator

The - operator has an overload for each pair of operands of the timestamptz, timestamp, and time data types. The result of subtracting two date values has data type integer. Try this:

drop function if exists f() cascade;
create function f()
  returns table(t text)
  language plpgsql
as $body$
declare
  d1 constant date           := '2021-01-13';
  d2 constant date           := '2021-02-17';

  t1 constant time           := '13:23:17';
  t2 constant time           := '15:37:43';

  ts1 constant timestamp     := '2021-01-13 13:23:17';
  ts2 constant timestamp     := '2021-02-17 15:37:43';

  tstz1 constant timestamptz := '2021-01-13 13:23:17 +04:00';
  tstz2 constant timestamptz := '2021-02-17 15:37:43 -01:00';

begin
  t := 'date:        '||(pg_typeof(d2    - d1   ))::text; return next;
  t := 'time:        '||(pg_typeof(t2    - t1   ))::text; return next;
  t := 'timestamp:   '||(pg_typeof(ts2   - ts1  ))::text; return next;
  t := 'timestamptz: '||(pg_typeof(tstz2 - tstz1))::text; return next;
end;
$body$;

select t from f();

This is the result:

 date:        integer
 time:        interval
 timestamp:   interval
 timestamptz: interval

The interval value that results from subtracting one moment from another (for the timestamptz, timestamp, or time data types) has, in general, a non-zero value for each of the dd and ss fields of the internal [mm, dd, ss] representation. The value of the mm field is always zero. The section The moment-moment overloads of the "-" operator for timestamptz, timestamp, and time explains the algorithm that produces the value and shows that, because it has two fields that have different rules for the semantics of the interval-moment overloads of the + and - operators, this approach for producing an interval value should be avoided. See the section Custom domain types for specializing the native interval functionality for the recommended alternative approach.

The moment-interval overloads of the "+" and "-" operators

The + and - operators have overloads for each pair of operands of each of the timestamptz, timestamp, and time data types with an interval operand. The notions that the section Two ways of conceiving of time: calendar-time and clock-time addresses are critical for the understanding of this functionality. The topic is explained carefully in the child page The moment-interval overloads of the "+" and "-" operators for timestamptz, timestamp, and time. This test is copied from that page:

select (
    '30 days '::interval = '720 hours'::interval and
    ' 1 month'::interval = ' 30 days '::interval and
    ' 1 month'::interval = '720 hours'::interval
  )::text;

The result is true, showing that (at least in an inexact sense), the three spellings '720 hours', '30 days', and '1 month' all denote the same interval value. Critically, though, '720 hours' is a clock-time-semantics notion while '30 days' and '1 month' are each calendar-time-semantics notions, though in subtly different ways. This explains the outcome of this test—again, copied from (but in a simplified form) the child page:

drop table if exists t;
create table t(
   t0               timestamptz primary key,
  "t0 + 720 hours"  timestamptz,
  "t0 + 30 days"    timestamptz,
  "t0 + 1 month"    timestamptz);

insert into t(t0) values ('2021-02-19 12:00:00 America/Los_Angeles');

set timezone = 'America/Los_Angeles';

update t set
  "t0 + 720 hours" = t0 + '720 hours' ::interval,
  "t0 + 30 days"   = t0 + '30 days'   ::interval,
  "t0 + 1 month"   = t0 + '1 month'   ::interval;

select
  t0,
  "t0 + 720 hours",
  "t0 + 30 days",
  "t0 + 1 month"
from t;

This is the result:

           t0           |     t0 + 720 hours     |      t0 + 30 days      |      t0 + 1 month
------------------------+------------------------+------------------------+------------------------
 2021-02-19 12:00:00-08 | 2021-03-21 13:00:00-07 | 2021-03-21 12:00:00-07 | 2021-03-19 12:00:00-07

The fact that adding the (inexactly) "same" value produces three different results motivates the careful, and rather tricky, discussion of clock-time and the two sub-flavors of calendar-time (days versus months and years).