PostgreSQL Tutorial

  • Home
  • Administration
  • Views
  • Triggers
  • Stored Procedures
  • Interfaces
    • PostgreSQL PHP
    • PostgreSQL Python
    • PostgreSQL JDBC
Home / PostgreSQL Tutorial / Compare Two Tables in PostgreSQL

Compare Two Tables in PostgreSQL

Summary: in this tutorial, you will learn various ways to compare two tables in PostgreSQL.

There are several ways to compare the content of two tables to find the differences between them. We will show you two commonly used techniques to compare data of two tables.

Compare two tables using EXCEPT and UNION operators

First, let’s create table two tables named foo and bar, and insert some sample data for the demonstration.

1
2
3
4
CREATE TABLE foo (
ID INT PRIMARY KEY,
NAME VARCHAR (50)
);

1
2
3
4
INSERT INTO foo (ID, NAME)
VALUES
(1, 'a'),
(2, 'b');

1
2
3
4
CREATE TABLE bar (
ID INT PRIMARY KEY,
NAME VARCHAR (50)
);

1
2
3
4
INSERT INTO bar (ID, NAME)
VALUES
(1, 'a'),
(2, 'b');

The foo table has the same structure and data as the bar table.

Next, we update one row in the bar table.

1
2
3
4
UPDATE bar
SET name = 'c'
WHERE
id = 2;

compare-two-tables-postgresql

Then, to find the rows in the foo table but not in the bar table, we use the following query:

1
2
3
4
5
6
7
8
9
10
11
12
13
SELECT
ID,
NAME,
'not in bar' AS note
FROM
foo
EXCEPT
SELECT
ID,
NAME,
'not in bar' AS note
FROM
bar

postgresql compare two tables: not in bar table
We used EXCEPT operator that returns the rows in the foo table but not in the bar table. We can apply the same technique to find the rows that are in the bar table but not in the foo table.

1
2
3
4
5
6
7
8
9
10
11
12
13
SELECT
ID,
NAME,
'not in foo' AS note
FROM
bar
EXCEPT
SELECT
ID,
NAME,
'not in foo' AS note
FROM
foo

compare two tables not in foo table
Finally, we use UNION operator to combine the result of both queries to find:

  • Rows in the bar table but not in the foo table
  • Rows in the foo table but not in the bar table.

compare two tables: result

Compare two tables using OUTER JOIN

We can use the outer join to compare two tables as follows:

1
2
3
4
5
6
7
8
9
SELECT
id,
name
FROM
foo
FULL OUTER JOIN bar USING (id, name)
WHERE
foo.id IS NULL
OR bar.id IS NULL;

It returns the differences between two tables:

postgresql compare two tables differences

To find the number of rows that are in the foo table but not bar table and vice versa, we use the COUNT function as follows:

1
2
3
4
5
6
7
8
SELECT
COUNT (*)
FROM
foo
FULL OUTER JOIN bar USING (id, name)
WHERE
foo.id IS NULL
OR bar.id IS NULL;

number of rows differences

In this tutorial, we have shown you two ways to compare two tables in PostgreSQL.

Previous Tutorial: PostgreSQL JSON
Next Tutorial: How to Generate a Random Number in A Range

PostgreSQL Quick Start

  • What is PostgreSQL?
  • Install PostgreSQL
  • Connect to Database
  • Download PostgreSQL Sample Database
  • Load Sample Database
  • Explore Server and Database Objects

PostgreSQL Fundamentals

  • PostgreSQL Select
  • PostgreSQL Order By
  • PostgreSQL Select Distinct
  • PostgreSQL Where
  • PostgreSQL LIMIT
  • PostgreSQL IN
  • PostgreSQL Between
  • PostgreSQL Like
  • PostgreSQL Inner Join
  • PostgreSQL Left Join
  • PostgreSQL Full Outer Join
  • PostgreSQL Cross Join
  • PostgreSQL Natural Join
  • PostgreSQL Group By
  • PostgreSQL Having
  • PostgreSQL Union
  • PostgreSQL Intersect
  • PostgreSQL Except
  • PostgreSQL Subquery
  • PostgreSQL Insert
  • PostgreSQL Update
  • PostgreSQL Delete
  • PostgreSQL Data Types
  • PostgreSQL Create Table
  • PostgreSQL Alter Table
  • PostgreSQL Drop Table
  • PostgreSQL Truncate Table
  • PostgreSQL CHECK Constraint
  • PostgreSQL Not-Null Constraint
  • PostgreSQL Foreign Key
  • PostgreSQL Primary Key
  • PostgreSQL UNIQUE Constraint

About PostgreSQL Tutorial

PostgreSQLTutorial.com is a website dedicated to developers and database administrators who are working on PostgreSQL database management system.

We constantly publish useful PostgreSQL tutorials to keep you up-to-date with the latest PostgreSQL features and technologies. All PostgreSQL tutorials are simple, easy-to-follow and practical.

Recent PostgreSQL Tutorials

  • PostgreSQL Recursive View
  • Learn PostgreSQL Recursive Query By Example
  • Creating Updatable Views Using the WITH CHECK OPTION Clause
  • PostgreSQL Upsert Using INSERT ON CONFLICT statement
  • How to Generate a Random Number in A Range
  • Using PostgreSQL ADD COLUMN to Add One or More Columns To a Table
  • PostgreSQL Character Types: CHAR, VARCHAR, and TEXT
  • Using PostgreSQL SERIAL To Create Auto-increment Column
  • PostgreSQL Boolean Data Type with Practical Examples
  • Understanding PostgreSQL Timestamp Data Types

More Tutorials

  • PostgreSQL PHP
  • PostgreSQL Python
  • PostgreSQL JDBC
  • PostgreSQL Functions
  • PostgreSQL Resources

Site Info

  • Home
  • About Us
  • Contact Us
  • Privacy Policy

Copyright © 2016 by PostgreSQL Tutorial Website. All Rights Reserved.