Join us on YugabyteDB Community Slack
Star us on
Get Started
Slack
GitHub
Get Started
v2.13 (preview) v2.12 (stable) v2.8 (earlier version) v2.6 (earlier version) v2.4 (earlier version) Unsupported versions
  • YUGABYTEDB CORE
    • Quick start
      • 1. Install YugabyteDB
      • 2. Create a local cluster
      • 3. Explore distributed SQL
      • 4. Build an application
        • Java
        • Node.js
        • Go
        • Python
        • Ruby
        • C#
        • PHP
        • C++
        • C
        • Scala
        • Rust
    • Explore
      • SQL features
        • SQL Feature Support
        • PostgreSQL Compatibility
        • Foreign Data Wrappers
        • Schemas and Tables
        • Data Types
        • Data Manipulation
        • Queries and Joins
        • Expressions and Operators
        • Stored Procedures
        • Triggers
        • Advanced features
          • Cursors
          • Table Partitioning
          • Views
          • Savepoints
          • Collations
        • Going beyond SQL
          • Follower reads
          • Tablespaces
        • PostgreSQL extensions
      • Fault tolerance
      • Horizontal scalability
        • Scaling Transactions
        • Sharding Data
      • Transactions
        • Distributed Transactions
        • Isolation Levels
        • Explicit Locking
      • Indexes and Constraints
        • Primary keys
        • Foreign keys
        • Secondary indexes
        • Unique indexes
        • Partial indexes
        • Expression indexes
        • Covering indexes
        • GIN indexes
        • Other constraints
      • JSON support
      • Multi-region deployments
        • Sync replication (3+ regions)
        • Async Replication (2+ regions)
        • Row-Level Geo-Partitioning
        • Read replicas
      • Query tuning
        • Introduction
        • Get query statistics using pg_stat_statements
        • Viewing live queries with pg_stat_activity
        • Analyzing queries with EXPLAIN
        • Optimizing YSQL queries using pg_hint_plan
      • Cluster management
        • Point-in-time recovery
      • Change data capture (CDC)
        • Debezium connector
        • Java CDC console
      • Security
      • Observability
        • Prometheus Integration
        • Grafana Dashboard
    • Drivers and ORMs
      • Java
        • JDBC drivers
        • Hibernate ORM
        • Supported versions
      • Go
        • Go drivers
        • Go ORMs
        • Supported versions
      • C#
        • C# drivers
        • C# ORMs
        • Supported versions
      • NodeJS
        • NodeJS drivers
        • NodeJS ORMs
        • Supported Versions
      • Python
        • Python drivers
        • Python ORMs
        • Supported versions
      • Rust
        • Diesel ORM
    • Develop
      • Learn app development
        • 1. SQL vs NoSQL
        • 2. Data modeling
        • 3. Data types
        • 4. ACID transactions
        • 5. Aggregations
        • 6. Batch operations
        • 7. Date and time
        • 8. Strings and text
        • 9. TTL for data expiration
      • Real-world examples
        • E-Commerce app
        • IoT fleet management
      • Explore sample apps
      • Best practices
      • Cloud-native development
        • Codespaces
        • Gitpod
    • Migrate
      • Migration process overview
      • Migrate from PostgreSQL
        • Convert a PostgreSQL schema
        • Migrate a PostgreSQL application
        • Export PostgreSQL data
        • Prepare a cluster
        • Import PostgreSQL data
        • Verify Migration
    • Deploy
      • Deployment checklist
      • Manual deployment
        • 1. System configuration
        • 2. Install software
        • 3. Start YB-Masters
        • 4. Start YB-TServers
        • 5. Verify deployment
      • Kubernetes
        • Single-zone
          • Open Source
          • Amazon EKS
          • Google Kubernetes Engine
          • Azure Kubernetes Service
        • Multi-zone
          • Amazon EKS
          • Google Kubernetes Engine
        • Multi-cluster
          • Google Kubernetes Engine
        • Best practices
        • Connect Clients
      • Docker
      • Public clouds
        • Amazon Web Services
        • Google Cloud Platform
        • Microsoft Azure
      • Multi-DC deployments
        • Three+ data center (3DC)
        • Asynchronous Replication
        • Read replica clusters
    • Benchmark
      • TPC-C
      • sysbench
      • YCSB
      • Key-value workload
      • Large datasets
      • Scalability
        • Scaling queries
      • Resilience
        • Jepsen testing
      • Performance Troubleshooting
    • Secure
      • Security checklist
      • Enable authentication
        • Enable users
        • Configure client authentication
      • Authentication methods
        • Password authentication
        • LDAP authentication
        • Host-based authentication
        • Trust authentication
      • Role-based access control
        • Overview
        • Manage users and roles
        • Grant privileges
        • Row-level security
        • Column-level security
      • Encryption in transit
        • Create server certificates
        • Enable server-to-server encryption
        • Enable client-to-server encryption
        • Connect to clusters
        • TLS and authentication
      • Encryption at rest
      • Column-level encryption
      • Audit logging
        • Configure audit logging
        • Session-Level Audit Logging
        • Object-Level Audit Logging
      • Vulnerability disclosure policy
    • Manage
      • Back up and restore
        • Export and import data
        • Snapshot and restore data
        • Point-in-time recovery
      • Migrate data
        • Bulk import
        • Bulk export
      • Change cluster configuration
      • Diagnostics reporting
      • Upgrade a deployment
      • Grow cluster
    • Troubleshoot
      • Troubleshooting
      • Cluster level issues
        • YCQL connection issues
        • YEDIS connection Issues
        • Recover tserver/master
        • Replace a failed YB-TServer
        • Replace a failed YB-Master
        • Manual remote bootstrap when a majority of peers fail
      • Node level issues
        • Check servers
        • Inspect logs
        • System statistics
        • Disk failure
        • Common error messages
    • Contribute
      • Core database
        • Contribution checklist
        • Build the source
        • Configure a CLion project
        • Run the tests
        • Coding style
      • Documentation
        • Docs checklist
        • Docs layout
        • Build the docs
          • Editor setup
        • Edit the docs
          • Docs page structure
          • Syntax diagrams
        • Style guide
  • YUGABYTEDB ANYWHERE
    • Overview
      • Install
      • Configure
    • Install
      • Prerequisites
      • Prepare the environment
      • Install software
      • Prepare nodes
      • Uninstall software
    • Configure
      • Create admin user
      • Configure cloud providers
      • Configure backup target
      • Configure alerts
    • Create deployments
      • Multi-zone universe
      • Multi-region universe
      • Multi-cloud universe
      • Read replica cluster
      • Asynchronous replication
    • Manage deployments
      • Start and stop processes
      • Eliminate an unresponsive node
      • Recover a node
      • Enable high availability
      • Edit configuration flags
      • Edit a universe
      • Delete a universe
      • Configure instance tags
      • Upgrade YugabyteDB
      • Migrate to Helm 3
    • Back up universes
      • Configure backup storage
      • Back up universe data
      • Restore universe data
      • Schedule data backups
    • Security
      • Security checklist
      • Configure ports
      • LDAP authentication
      • Authorization
      • Create a KMS configuration
      • Enable encryption at rest
      • Enable encryption in transit
      • Network security
    • Alerts and monitoring
      • Alerts
      • Live Queries dashboard
      • Slow Queries dashboard
    • Troubleshoot
      • Install and upgrade issues
      • Universe issues
    • Administer
      • Back up YugabyteDB Anywhere
      • Authenticate with LDAP
    • Upgrade
      • Upgrade Kubernetes installation
      • Upgrade using Replicated
  • YUGABYTEDB MANAGED
    • Overview
    • Quick start
      • Create a free cluster
      • Connect to the cluster
      • Explore distributed SQL
      • Build an application
        • Before you begin
        • Java
        • Go
        • Python
        • Node.js
        • C
        • C++
        • C#
        • Ruby
        • Rust
        • PHP
    • Deploy clusters
      • Planning a cluster
      • Create a free cluster
      • Create a standard cluster
      • VPC network
        • Overview
        • VPCs
        • Peering connections
        • Create a VPC Network
    • Secure clusters
      • IP allow lists
      • Database authorization
      • Add database users
      • Encryption in transit
      • Audit account activity
    • Connect to clusters
      • Cloud Shell
      • Client shell
      • Connect applications
    • Alerts and monitoring
      • Alerts
      • Performance metrics
      • Live queries
      • Slow YSQL queries
      • Cluster activity
    • Manage clusters
      • Scale and configure clusters
      • Backup and restore
      • Maintenance windows
      • Create extensions
    • Administration and billing
      • Manage account access
      • Manage billing
      • Cluster costs
    • Example applications
      • Connect a Spring application
      • Connect a YCQL Java application
      • Hasura Cloud
      • Deploy a GraphQL application
    • Security architecture
      • Security architecture
      • Shared responsibility model
    • Troubleshoot
    • YugabyteDB Managed FAQ
    • What's new
  • INTEGRATIONS
    • Apache Kafka
    • Apache Spark
    • Debezium
    • Django REST framework
    • Entity Framework
    • Flyway
    • GORM
    • Hasura
      • Application Development
      • Benchmarking
    • JanusGraph
    • KairosDB
    • Liquibase
    • Metabase
    • Presto
    • Prisma
    • Sequelize
    • Spring Framework
      • Spring Data YugabyteDB
      • Spring Data JPA
      • Spring Data Cassandra
    • SQLAlchemy
    • WSO2 Identity Server
    • YSQL Loader
    • YugabyteDB JDBC driver
  • REFERENCE
    • Architecture
      • Design goals
      • Key concepts
        • Universe
        • YB-TServer Service
        • YB-Master Service
      • Core functions
        • Universe creation
        • Table creation
        • Write IO path
        • Read IO path
        • High availability
      • Layered architecture
      • Query layer
        • Overview
      • DocDB transactions layer
        • Transactions overview
        • Transaction isolation levels
        • Explicit locking
        • Read Committed
        • Single-row transactions
        • Distributed transactions
        • Transactional IO path
      • DocDB sharding layer
        • Hash & range sharding
        • Tablet splitting
        • Colocated tables
      • DocDB replication layer
        • Replication
        • xCluster replication
        • Read replicas
        • Change data capture (CDC)
      • DocDB storage layer
        • Persistence
        • Performance
    • APIs
      • YSQL
        • The SQL language
          • SQL statements
            • ABORT
            • ALTER DATABASE
            • ALTER DEFAULT PRIVILEGES
            • ALTER DOMAIN
            • ALTER FOREIGN DATA WRAPPER
            • ALTER FOREIGN TABLE
            • ALTER GROUP
            • ALTER POLICY
            • ALTER ROLE
            • ALTER SEQUENCE
            • ALTER SERVER
            • ALTER TABLE
            • ALTER USER
            • ANALYZE
            • BEGIN
            • CALL
            • COMMENT
            • COMMIT
            • COPY
            • CREATE AGGREGATE
            • CREATE CAST
            • CREATE DATABASE
            • CREATE DOMAIN
            • CREATE EXTENSION
            • CREATE FOREIGN DATA WRAPPER
            • CREATE FOREIGN TABLE
            • CREATE FUNCTION
            • CREATE GROUP
            • CREATE INDEX
            • CREATE MATERIALIZED VIEW
            • CREATE OPERATOR
            • CREATE OPERATOR CLASS
            • CREATE POLICY
            • CREATE PROCEDURE
            • CREATE ROLE
            • CREATE RULE
            • CREATE SCHEMA
            • CREATE SEQUENCE
            • CREATE SERVER
            • CREATE TABLE
            • CREATE TABLE AS
            • CREATE TRIGGER
            • CREATE TYPE
            • CREATE USER
            • CREATE USER MAPPING
            • CREATE VIEW
            • DEALLOCATE
            • DELETE
            • DO
            • DROP AGGREGATE
            • DROP CAST
            • DROP DATABASE
            • DROP DOMAIN
            • DROP EXTENSION
            • DROP FOREIGN DATA WRAPPER
            • DROP FOREIGN TABLE
            • DROP FUNCTION
            • DROP GROUP
            • DROP MATERIALIZED VIEW
            • DROP OPERATOR
            • DROP OPERATOR CLASS
            • DROP OWNED
            • DROP POLICY
            • DROP PROCEDURE
            • DROP ROLE
            • DROP RULE
            • DROP SEQUENCE
            • DROP SERVER
            • DROP TABLE
            • DROP TRIGGER
            • DROP TYPE
            • DROP USER
            • END
            • EXECUTE
            • EXPLAIN
            • GRANT
            • IMPORT FOREIGN SCHEMA
            • INSERT
            • LOCK
            • PREPARE
            • REASSIGN OWNED
            • REFRESH MATERIALIZED VIEW
            • RELEASE SAVEPOINT
            • RESET
            • REVOKE
            • ROLLBACK
            • ROLLBACK TO SAVEPOINT
            • SAVEPOINT
            • SELECT
            • SET
            • SET CONSTRAINTS
            • SET ROLE
            • SET SESSION AUTHORIZATION
            • SET TRANSACTION
            • SHOW
            • SHOW TRANSACTION
            • TRUNCATE
            • UPDATE
            • VALUES
          • WITH clause
            • WITH clause—SQL syntax and semantics
            • recursive CTE
            • case study—traversing an employee hierarchy
            • traversing general graphs
              • graph representation
              • common code
              • undirected cyclic graph
              • directed cyclic graph
              • directed acyclic graph
              • rooted tree
              • Unique containing paths
              • Stress testing find_paths()
            • case study—Bacon Numbers from IMDb
              • Bacon numbers for synthetic data
              • Bacon numbers for IMDb data
        • Data types
          • Array
            • array[] constructor
            • Literals
              • Text typecasting and literals
              • Array of primitive values
              • Row
              • Array of rows
            • FOREACH loop (PL/pgSQL)
            • array of DOMAINs
            • Functions and operators
              • ANY and ALL
              • Array comparison
              • Array slice operator
              • Array concatenation
              • Array properties
              • array_agg(), unnest(), generate_subscripts()
              • array_fill()
              • array_position(), array_positions()
              • array_remove()
              • array_replace() / set value
              • array_to_string()
              • string_to_array()
          • Binary
          • Boolean
          • Character
          • Date and time
            • Conceptual background
            • Timezones and UTC offsets
              • Catalog views
              • Extended_timezone_names
                • Unrestricted full projection
                • Real timezones with DST
                • Real timezones no DST
                • Synthetic timezones no DST
              • Offset/timezone-sensitive operations
                • Timestamptz to/from timestamp conversion
                • Pure 'day' interval arithmetic
              • Four ways to specify offset
                • Name-resolution rules
                  • 1 case-insensitive resolution
                  • 2 ~names.abbrev never searched
                  • 3 'set timezone' string not resolved in ~abbrevs.abbrev
                  • 4 ~abbrevs.abbrev before ~names.name
                  • Helper functions
              • Syntax contexts for offset
              • Recommended practice
            • Typecasting between date-time and text-values
            • Semantics of the date-time data types
              • Date data type
              • Time data type
              • Plain timestamp and timestamptz
              • Interval data type
                • Interval representation
                  • Ad hoc examples
                  • Representation model
                • Interval value limits
                • Declaring intervals
                • Justify() and extract(epoch...)
                • Interval arithmetic
                  • Interval-interval comparison
                  • Interval-interval addition and subtraction
                  • Interval-number multiplication
                  • Moment-moment overloads of "-"
                  • Moment-interval overloads of "+" and "-"
                • Custom interval domains
                • Interval utility functions
            • Typecasting between date-time datatypes
            • Operators
              • Test comparison overloads
              • Test addition overloads
              • Test subtraction overloads
              • Test multiplication overloads
              • Test division overloads
            • General-purpose functions
              • Creating date-time values
              • Manipulating date-time values
              • Current date-time moment
              • Delaying execution
              • Miscellaneous
                • Function age()
                • Function extract() | date_part()
                • Implementations that model the overlaps operator
            • Formatting functions
            • Case study—SQL stopwatch
            • Download & install the date-time utilities
            • ToC
          • JSON
            • JSON literals
            • Primitive and compound data types
            • Code example conventions
            • Indexes and check constraints
            • Functions & operators
              • ::jsonb, ::json, ::text (typecast)
              • ->, ->>, #>, #>> (JSON subvalues)
              • - and #- (remove)
              • || (concatenation)
              • = (equality)
              • @> and <@ (containment)
              • ? and ?| and ?& (key or value existence)
              • array_to_json()
              • jsonb_agg()
              • jsonb_array_elements()
              • jsonb_array_elements_text()
              • jsonb_array_length()
              • jsonb_build_object()
              • jsonb_build_array()
              • jsonb_each()
              • jsonb_each_text()
              • jsonb_extract_path()
              • jsonb_extract_path_text() and json_extract_path_text()
              • jsonb_object()
              • jsonb_object_agg()
              • jsonb_object_keys()
              • jsonb_populate_record()
              • jsonb_populate_recordset()
              • jsonb_pretty()
              • jsonb_set() and jsonb_insert()
              • jsonb_strip_nulls()
              • jsonb_to_record()
              • jsonb_to_recordset()
              • jsonb_typeof()
              • row_to_json()
              • to_jsonb()
          • Money
          • Numeric
          • Range
          • Serial
          • UUID
        • Functions and operators
          • Aggregate functions
            • Informal functionality overview
            • Invocation syntax and semantics
            • grouping sets, rollup, cube
            • Per function signature and purpose
              • avg(), count(), max(), min(), sum()
              • array_agg(), string_agg(), jsonb_agg(), jsonb_object_agg()
              • bit_and(), bit_or(), bool_and(), bool_or()
              • variance(), var_pop(), var_samp(), stddev(), stddev_pop(), stddev_samp()
              • linear regression
                • covar_pop(), covar_samp(), corr()
                • regr_%()
              • mode(), percentile_disc(), percentile_cont()
              • rank(), dense_rank(), percent_rank(), cume_dist()
            • case study—percentile_cont() and the "68–95–99.7" rule
            • case study—linear regression on COVID data
              • Download the COVIDcast data
              • Ingest the COVIDcast data
                • Inspect the COVIDcast data
                • Copy the .csv files to staging tables
                • Check staged data conforms to the rules
                • Join the staged data into a single table
                • SQL scripts
                  • Create cr_staging_tables()
                  • Create cr_copy_from_scripts()
                  • Create assert_assumptions_ok()
                  • Create xform_to_covidcast_fb_survey_results()
                  • ingest-the-data.sql
              • Analyze the COVIDcast data
                • symptoms vs mask-wearing by day
                • Data for scatter-plot for 21-Oct-2020
                • Scatter-plot for 21-Oct-2020
                • SQL scripts
                  • analysis-queries.sql
                  • synthetic-data.sql
          • currval()
          • lastval()
          • nextval()
          • Window functions
            • Informal functionality overview
            • Invocation syntax and semantics
            • Per function signature and purpose
              • row_number(), rank() and dense_rank()
              • percent_rank(), cume_dist() and ntile()
              • first_value(), nth_value(), last_value()
              • lag(), lead()
              • Tables for the code examples
                • table t1
                • table t2
                • table t3
                • table t4
            • case study—analyzing a normal distribution
              • Bucket allocation scheme
              • do_clean_start.sql
              • cr_show_t4.sql
              • cr_dp_views.sql
              • cr_int_views.sql
              • cr_pr_cd_equality_report.sql
              • cr_bucket_using_width_bucket.sql
              • cr_bucket_dedicated_code.sql
              • do_assert_bucket_ok
              • cr_histogram.sql
              • cr_do_ntile.sql
              • cr_do_percent_rank.sql
              • cr_do_cume_dist.sql
              • do_populate_results.sql
              • do_report_results.sql
              • do_compare_dp_results.sql
              • do_demo.sql
              • Reports
                • Histogram report
                • dp-results
                • compare-dp-results
                • int-results
          • yb_hash_code()
        • Keywords
        • Reserved names
      • YCQL
        • ALTER KEYSPACE
        • ALTER ROLE
        • ALTER TABLE
        • CREATE INDEX
        • CREATE KEYSPACE
        • CREATE ROLE
        • CREATE TABLE
        • CREATE TYPE
        • DROP INDEX
        • DROP KEYSPACE
        • DROP ROLE
        • DROP TABLE
        • DROP TYPE
        • GRANT PERMISSION
        • GRANT ROLE
        • REVOKE PERMISSION
        • REVOKE ROLE
        • USE
        • INSERT
        • SELECT
        • EXPLAIN
        • UPDATE
        • DELETE
        • TRANSACTION
        • TRUNCATE
        • Simple expressions
        • Subscripted expressions
        • Function call
        • Operators
        • BLOB
        • BOOLEAN
        • Collection
        • FROZEN
        • INET
        • Integer and counter
        • Non-integer
        • TEXT
        • DATE, TIME, and TIMESTAMP
        • UUID and TIMEUUID
        • JSONB
        • Date and time
        • BATCH
    • CLIs
      • yb-ctl
      • yb-docker-ctl
      • ysqlsh
      • ycqlsh
      • yb-admin
      • yb-ts-cli
      • ysql_dump
      • ysql_dumpall
    • Configuration
      • yb-tserver
      • yb-master
      • yugabyted
      • Default ports
    • Drivers and ORMs
      • JDBC Drivers
      • C# Drivers
      • Go Drivers
      • Python Drivers
      • Client drivers for YSQL
      • Client drivers for YCQL
    • Connectors
      • Kafka Connect YugabyteDB
    • Third party tools
      • pgAdmin
      • Apache Superset
      • Arctype
      • DBeaver
      • TablePlus
      • DbSchema
      • SQL Workbench/J
      • Cassandra Workbench
    • Sample datasets
      • Chinook
      • Northwind
      • PgExercises
      • SportsDB
      • Retail Analytics
  • RELEASES
    • Releases overview
      • v2.13 series (preview)
      • v2.12 series (stable)
      • v2.11 series
      • v2.9 series
      • v2.8 series
      • v2.7 series
      • v2.6 series
      • v2.5 series
      • v2.4 series
      • v2.3 series
      • v2.2 series
      • v2.1 series
      • v2.0 series
      • v1.3 series
      • v1.2 series
    • Release versioning
  • FAQ
    • Comparisons
      • Amazon Aurora
      • Google Cloud Spanner
      • CockroachDB
      • TiDB
      • Vitess
      • MongoDB
      • FoundationDB
      • Amazon DynamoDB
      • Azure Cosmos DB
      • Apache Cassandra
      • PostgreSQL
      • Redis in-memory store
      • Apache HBase
    • General FAQ
    • Operations FAQ
    • API compatibility FAQ
    • YugabyteDB Anywhere FAQ
  • MISC
    • YEDIS
      • Quick start
      • Develop
        • Build an application
        • C#
        • C++
        • Go
        • Java
        • NodeJS
        • Python
      • API reference
        • APPEND
        • AUTH
        • CONFIG
        • CREATEDB
        • DELETEDB
        • LISTDB
        • SELECT
        • DEL
        • ECHO
        • EXISTS
        • EXPIRE
        • EXPIREAT
        • FLUSHALL
        • FLUSHDB
        • GET
        • GETRANGE
        • GETSET
        • HDEL
        • HEXISTS
        • HGET
        • HGETALL
        • HINCRBY
        • HKEYS
        • HLEN
        • HMGET
        • HMSET
        • HSET
        • HSTRLEN
        • HVALS
        • INCR
        • INCRBY
        • KEYS
        • MONITOR
        • PEXPIRE
        • PEXPIREAT
        • PTTL
        • ROLE
        • SADD
        • SCARD
        • RENAME
        • SET
        • SETEX
        • PSETEX
        • SETRANGE
        • SISMEMBER
        • SMEMBERS
        • SREM
        • STRLEN
        • ZRANGE
        • TSADD
        • TSCARD
        • TSGET
        • TSLASTN
        • TSRANGEBYTIME
        • TSREM
        • TSREVRANGEBYTIME
        • TTL
        • ZADD
        • ZCARD
        • ZRANGEBYSCORE
        • ZREM
        • ZREVRANGE
        • ZSCORE
        • PUBSUB
        • PUBLISH
        • SUBSCRIBE
        • UNSUBSCRIBE
        • PSUBSCRIBE
        • PUNSUBSCRIBE
    • Legal
      • Third party software
> APIs > YSQL > Data types > Date and time > General-purpose functions > Miscellaneous >

Implementations that model the overlaps operator

Report a doc issue Suggest new content Contributor guide
  • The function modeled_overlaps(timestamp, timestamp, timestamp, timestamp) returns boolean
  • The function modeled_overlaps_vs_overlaps(timestamp, timestamp, timestamp, timestamp) returns modeled_overlaps_vs_overlaps_result
  • The function modeled_overlaps_vs_overlaps_display(timestamp, timestamp, timestamp, timestamp) returns text
  • The function modeled_overlaps_vs_overlaps_report() returns table(z text)

The function modeled_overlaps(timestamp, timestamp, timestamp, timestamp) returns boolean

This function models the overlaps semantics using two distinct approaches:

  • Using the && operator with two range values.
  • From first principles using ordinary if-the-else logic.

It considers just this invocation syntax:

overlaps_result ◄— (left-duration-bound-1, left-duration-bound-2) overlaps (right-duration-bound-1, right-duration-bound-2)

The other overloads:

  • that define one duration using a pair of moments and one using a moment and a duration size
  • that define both durations using a moment and a duration size

can be trivially expressed as wrappers around the overload that defines both durations using a pair of moments.

The model addresses just the overload that specifies each duration by a pair of plain timestamp bounds. The corresponding overloads for plain time and timestamptz can be trivially derived from this.

This page's parent page, in the section overlaps semantics in prose, explained that the overlaps operator result is insensitive, for each of the two durations on which it acts, to the ordering of the moment arguments that define the duration's bounds—and that it is also insensitive to which duration is given as the left duration and which is given as the right duration. However, the implementation needs to distinguish between the start and the finish moments and needs to know how the two durations are mutually ordered. In other words, it models this invocation syntax:

overlaps_result ◄— (earlier-duration-start-moment, earlier-duration-finish-moment) overlaps (later-duration-start-moment, later-duration-finish-moment)

The implementation therefore starts by deriving these values:

earlier_start, earlier_finish, later_start, later_finish

from these input values:

left_1, left_2, right_1, right_2

Create the function modeled_overlaps() thus:

drop function if exists modeled_overlaps(timestamp, timestamp, timestamp, timestamp) cascade;

create function modeled_overlaps(left_1 in timestamp, left_2 in timestamp, right_1 in timestamp, right_2 in timestamp)
  returns boolean
  language plpgsql
as $body$
declare
  left_start       constant timestamp not null := least   (left_1,  left_2);
  left_finish      constant timestamp not null := greatest(left_1,  left_2);
  right_start      constant timestamp not null := least   (right_1, right_2);
  right_finish     constant timestamp not null := greatest(right_1, right_2);

  left_is_earlier  constant boolean   not null :=
    case
      when left_start < right_start then true
      when left_start > right_start then false
      else
        -- Here when left_start and right_start coincide
        case
          when left_finish < right_finish then true
          else                           false
        end
    end;

  earlier_start    timestamp not null := '-infinity'; -- convenient initial value;
  earlier_finish   timestamp not null := earlier_start;
  later_start      timestamp not null := earlier_start;
  later_finish     timestamp not null := earlier_start;
begin
  if left_is_earlier then
    earlier_start  := left_start;
    earlier_finish := left_finish;
    later_start    := right_start;
    later_finish   := right_finish;
  else
    earlier_start  := right_start;
    earlier_finish := right_finish;
    later_start    := left_start;
    later_finish   := left_finish;
  end if;
  declare
    -- Modeled using the && operator with two range values.
    -- Accommodate the fact that if the bounds of a '[)' range, r, coincide,
    -- then isempty(r) evaluates to TRUE by using a '[]' range instead.
    r1 constant tsrange not null :=
      case
        when earlier_start = earlier_finish then tsrange(earlier_start, earlier_finish, '[]')
        else                                     tsrange(earlier_start, earlier_finish, '[)')
      end;

    r2 constant tsrange not null :=
      case
        when later_start = later_finish then tsrange(later_start, later_finish, '[]')
        else                                 tsrange(later_start, later_finish, '[)')
      end;

    modeled_using_ranges boolean not null := r1 && r2;

    -- Modeled from first principles using ordinary if-the-else logic.
    modeled_from_first_principles boolean not null :=
      case
        -- Special case: both are instants
        when (earlier_finish = earlier_start) and (later_finish = later_start) then
          case
            when earlier_start = later_start then true
            else                                  false
          end

        -- Special case: earlier is instant
        when (earlier_finish = earlier_start) and (later_finish > later_start) then
          case
            when earlier_start = later_start then true
            else                                  false
          end

        -- Later is instant doesn't need special case treatment.

        -- Neither is instant
        else
          (earlier_start <= later_start) and (earlier_finish > later_start)
      end;
  begin
    assert (modeled_from_first_principles = modeled_using_ranges), 'Assert failed';
    return modeled_from_first_principles;
  end;
end;
$body$;

The function modeled_overlaps_vs_overlaps(timestamp, timestamp, timestamp, timestamp) returns modeled_overlaps_vs_overlaps_result

This function returns a user-defined type value that represents the return value from the native overlaps operator together with the return value from modeled_overlaps(), for the same parameterization of the two durations, as a pair of boolean values.

Create the type modeled_overlaps_vs_overlaps_result and the function modeled_overlaps_vs_overlaps) thus:

drop type if exists modeled_overlaps_vs_overlaps_result cascade;

create type modeled_overlaps_vs_overlaps_result as (o boolean, m boolean);

drop function if exists modeled_overlaps_vs_overlaps(timestamp, timestamp, timestamp, timestamp) cascade;

create function modeled_overlaps_vs_overlaps(left_1 in timestamp, left_2 in timestamp, right_1 in timestamp, right_2 in timestamp)
  returns modeled_overlaps_vs_overlaps_result
  language plpgsql
as $body$
declare
  o     constant boolean not null :=                 (left_1, left_2) overlaps (right_1, right_2);
  m     constant boolean not null := modeled_overlaps(left_1, left_2,           right_1, right_2);
begin
  return (o, m)::modeled_overlaps_vs_overlaps_result;
end;
$body$;

The function modeled_overlaps_vs_overlaps_display(timestamp, timestamp, timestamp, timestamp) returns text

This function creates a text value from the parameterization of the two durations that encodes:

  • the left_1, left_2, right_1, and right_2 plain timestamp values
  • the result, true or false from the native overlaps operator
  • only if the result from modeled_overlaps() is different from the result from the native overlaps operator, then it appends DISAGREE.

It also adds a significant test of its own. For each supplied parameterization, (left_1, left_2, right_1, right_2), it invokes modeled_overlaps_vs_overlaps() with each of the eight parameter orderings that supposedly express the same semantics:

  • (left_1, left_2, right_1, right_2)
  • (left_2, left_1, right_1, right_2)
  • (left_1, left_2, right_2, right_1)
  • (left_2, left_1, right_2, right_1)
  • (right_1, right_2, left_1, left_2)
  • (right_2, right_1, left_1, left_2)
  • (right_1, right_2, left_2, left_1)
  • (right_2, right_1, left_2, left_1)

and it tests that all of these invocations produce the same result.

First create the helper procedure assert_r1_equals_r(int, modeled_overlaps_vs_overlaps_result, modeled_overlaps_vs_overlaps_result) to test if the result from the invocation that uses one of the second through the eighth orderings is identical to the result from the invocation that uses the first ordering.

drop procedure if exists assert_r1_equals_r(int, modeled_overlaps_vs_overlaps_result, modeled_overlaps_vs_overlaps_result) cascade;

create procedure assert_r1_equals_r(test_nr in int, r1 in modeled_overlaps_vs_overlaps_result, r in modeled_overlaps_vs_overlaps_result)
  language plpgsql
as $body$
declare
  o1 constant boolean not null := r1.o;
  m1 constant boolean not null := r1.m;
  o  constant boolean not null :=  r.o;
  m  constant boolean not null :=  r.m;

  msg constant text not null := 'Test number '||test_nr::text||' assert failed';
begin
  assert ((o1 = o) and (m1 = m)), msg;
end;
$body$;

Now create the function modeled_overlaps_vs_overlaps_display():

drop function if exists modeled_overlaps_vs_overlaps_display(timestamp, timestamp, timestamp, timestamp) cascade;

create function modeled_overlaps_vs_overlaps_display(left_1 in timestamp, left_2 in timestamp, right_1 in timestamp, right_2 in timestamp)
  returns text
  language plpgsql
as $body$
declare
  input constant text      not null := rpad(left_1||', '  ::text, 29)||
                                       rpad(left_2        ::text, 27)||' |   ' ||
                                       rpad(right_1||', ' ::text, 29)||
                                       rpad(right_2       ::text, 27)||'   ';

  o1             boolean   not null := false;
  m1             boolean   not null := false;
  o              boolean   not null := false;
  m              boolean   not null := false;

  r              modeled_overlaps_vs_overlaps_result;
  r1             modeled_overlaps_vs_overlaps_result;
begin
  for j in 1..8 loop
    case j
      when 1 then
        r1 := modeled_overlaps_vs_overlaps(left_1, left_2, right_1, right_2);
        o1 := r1.o;
        m1 := r1.m;

      when 2 then
        r  := modeled_overlaps_vs_overlaps(left_2, left_1, right_1, right_2);
        call assert_r1_equals_r(1, r1, r);

      when 3 then
        r  := modeled_overlaps_vs_overlaps(left_1, left_2, right_2, right_1);
        call assert_r1_equals_r(2, r1, r);

      when 4 then
        r  := modeled_overlaps_vs_overlaps(left_2, left_1, right_2, right_1);
        call assert_r1_equals_r(3, r1, r);

      when 5 then
        r  := modeled_overlaps_vs_overlaps(right_1, right_2, left_1, left_2);
        call assert_r1_equals_r(4, r1, r);

      when 6 then
        r  := modeled_overlaps_vs_overlaps(right_2, right_1, left_1, left_2);
        call assert_r1_equals_r(5, r1, r);

      when 7 then
        r  := modeled_overlaps_vs_overlaps(right_1, right_2, left_2, left_1);
        call assert_r1_equals_r(6, r1, r);

      when 8 then
        r  := modeled_overlaps_vs_overlaps(right_2, right_1, left_2, left_1);
        call assert_r1_equals_r(7, r1, r);
    end case;

    return
      case (m1 = o1)
        when true then input||o1::text
        else           input||rpad(o1::text, 6)||'DISAGREE'
      end;
  end loop;
end;
$body$;

The function modeled_overlaps_vs_overlaps_report() returns table(z text)

This table function simply invokes modeled_overlaps_vs_overlaps_display() for all of the parameterizations that correspond to the interesting cases that are shown in the picture in this page's parent page in the section overlaps semantics in pictures. It also adds a few more tests. Create it thus:

drop function if exists modeled_overlaps_vs_overlaps_report() cascade;

create function modeled_overlaps_vs_overlaps_report()
  returns table(z text)
  language plpgsql
as $body$
begin
  z := 'TWO FINITE DURATIONS';                                                          return next;
  z := '--------------------';                                                          return next;
  z := '';                                                                              return next;

  z := ' 1. Durations do not overlap               '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-05-15', '2000-08-15', '2000-12-15');                     return next;

  z := ' 2. Right start = left end                 '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-05-15', '2000-05-15', '2000-12-15');                     return next;

  z := ' 3. Durations overlap                      '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-08-15', '2000-05-15', '2000-12-15');                     return next;

  z := ' 3. Durations overlap by 1 microsec        '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-06-15 00:00:00.000001', '2000-06-15', '2000-12-15');     return next;

  z := ' 3. Durations overlap by 1 microsec        '||
        modeled_overlaps_vs_overlaps_display
          ('2000-06-15', '2000-12-15', '2000-01-15', '2000-06-15 00:00:00.000001');     return next;

  z := ' 4. Contained                              '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-12-15', '2000-05-15', '2000-08-15');                     return next;

  z := ' 4. Contained, co-inciding at left         '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-06-15', '2000-01-15', '2000-08-15');                     return next;

  z := ' 4. Contained, co-inciding at right        '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-06-15', '2000-02-15', '2000-06-15');                     return next;

  z := ' 4. Durations coincide                     '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-06-15', '2000-01-15', '2000-06-15');                     return next;

  z := '';                                                                              return next;
  z := 'ONE INSTANT, ONE FINITE DURATION';                                              return next;
  z := '--------------------------------';                                              return next;
  z := '';                                                                              return next;

  z := ' 5. Instant before duration                '||
        modeled_overlaps_vs_overlaps_display
          ('2000-02-15', '2000-02-15', '2000-03-15', '2000-04-15');                     return next;

  z := ' 6. Instant coincides with duration start  '||
        modeled_overlaps_vs_overlaps_display
          ('2000-02-15', '2000-02-15', '2000-02-15', '2000-03-15');                     return next;

  z := ' 7. Instant within duration                '||
        modeled_overlaps_vs_overlaps_display
          ('2000-02-15', '2000-02-15', '2000-01-15', '2000-03-15');                     return next;

  z := ' 8. Instant coincides with duration end    '||
        modeled_overlaps_vs_overlaps_display
          ('2000-02-15', '2000-02-15', '2000-01-15', '2000-02-15');                     return next;

  z := ' 9. Instant after duration                 '||
        modeled_overlaps_vs_overlaps_display
          ('2000-05-15', '2000-05-15', '2000-03-15', '2000-04-15');                     return next;

  z := '';                                                                              return next;
  z := 'TWO INSTANTS';                                                                  return next;
  z := '------------';                                                                  return next;
  z := '';                                                                              return next;

  z := '10. Instants differ                        '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-01-15', '2000-06-15', '2000-06-15');                     return next;

  z := '11. Instants coincide                      '||
        modeled_overlaps_vs_overlaps_display
          ('2000-01-15', '2000-01-15', '2000-01-15', '2000-01-15');                     return next;
end;
$body$;

Invoke it thus:

select z from modeled_overlaps_vs_overlaps_report();

This is the result:

 TWO FINITE DURATIONS
 --------------------

  1. Durations do not overlap               2000-01-15 00:00:00,         2000-05-15 00:00:00         |   2000-08-15 00:00:00,         2000-12-15 00:00:00           false
  2. Right start = left end                 2000-01-15 00:00:00,         2000-05-15 00:00:00         |   2000-05-15 00:00:00,         2000-12-15 00:00:00           false
  3. Durations overlap                      2000-01-15 00:00:00,         2000-08-15 00:00:00         |   2000-05-15 00:00:00,         2000-12-15 00:00:00           true
  3. Durations overlap by 1 microsec        2000-01-15 00:00:00,         2000-06-15 00:00:00.000001  |   2000-06-15 00:00:00,         2000-12-15 00:00:00           true
  3. Durations overlap by 1 microsec        2000-06-15 00:00:00,         2000-12-15 00:00:00         |   2000-01-15 00:00:00,         2000-06-15 00:00:00.000001    true
  4. Contained                              2000-01-15 00:00:00,         2000-12-15 00:00:00         |   2000-05-15 00:00:00,         2000-08-15 00:00:00           true
  4. Contained, co-inciding at left         2000-01-15 00:00:00,         2000-06-15 00:00:00         |   2000-01-15 00:00:00,         2000-08-15 00:00:00           true
  4. Contained, co-inciding at right        2000-01-15 00:00:00,         2000-06-15 00:00:00         |   2000-02-15 00:00:00,         2000-06-15 00:00:00           true
  4. Durations coincide                     2000-01-15 00:00:00,         2000-06-15 00:00:00         |   2000-01-15 00:00:00,         2000-06-15 00:00:00           true

 ONE INSTANT, ONE FINITE DURATION
 --------------------------------

  5. Instant before duration                2000-02-15 00:00:00,         2000-02-15 00:00:00         |   2000-03-15 00:00:00,         2000-04-15 00:00:00           false
  6. Instant coincides with duration start  2000-02-15 00:00:00,         2000-02-15 00:00:00         |   2000-02-15 00:00:00,         2000-03-15 00:00:00           true
  7. Instant within duration                2000-02-15 00:00:00,         2000-02-15 00:00:00         |   2000-01-15 00:00:00,         2000-03-15 00:00:00           true
  8. Instant coincides with duration end    2000-02-15 00:00:00,         2000-02-15 00:00:00         |   2000-01-15 00:00:00,         2000-02-15 00:00:00           false
  9. Instant after duration                 2000-05-15 00:00:00,         2000-05-15 00:00:00         |   2000-03-15 00:00:00,         2000-04-15 00:00:00           false

 TWO INSTANTS
 ------------

 10. Instants differ                        2000-01-15 00:00:00,         2000-01-15 00:00:00         |   2000-06-15 00:00:00,         2000-06-15 00:00:00           false
 11. Instants coincide                      2000-01-15 00:00:00,         2000-01-15 00:00:00         |   2000-01-15 00:00:00,         2000-01-15 00:00:00           true

This is the same output that was shown on this page's parent page in the section Two implementations that model the 'overlaps' semantics and that produce the same results.

  • The function modeled_overlaps(timestamp, timestamp, timestamp, timestamp) returns boolean
  • The function modeled_overlaps_vs_overlaps(timestamp, timestamp, timestamp, timestamp) returns modeled_overlaps_vs_overlaps_result
  • The function modeled_overlaps_vs_overlaps_display(timestamp, timestamp, timestamp, timestamp) returns text
  • The function modeled_overlaps_vs_overlaps_report() returns table(z text)
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.