DEV Community

Cover image for Normalization and Relational Division in SQL and MongoDB
Franck Pachot
Franck Pachot

Posted on

3

Normalization and Relational Division in SQL and MongoDB

MongoDB promotes document data modeling rather than the highest normal forms of a relational model. To understand this approach, it's interesting to examine the reasons why E. F. Codd introduced normalization, as he describes in his article NORMALIZED DATA BASE STRUCTURE: A BRIEF TUTORIAL (1971), and compare with modern applications design:

make formatted data bases readily accessible to users (especially casual users) who have little or no training in programming

casual user at a terminal often has occasion to require tables to be printed out or displayed

Normalizing data structures into a set of two-dimensional tables was originally intended to simplify these structures for non-programmers and interactive users, a role taken by data scientists today. They accessed databases through early computer devices (TTY on CRT terminals and dot matrix printers).
This approach contrasts with the modern graphical user interface experience, where users can navigate and unfold nested structures using a mouse click.

Moreover, when the database client is a program rather than a human, it interacts with object-oriented structures that form a graph of interconnected objects instead of independent tables. In both cases, a document model, whether normalized or not, can be a better fit than the set of tables described by Codd (as long as data consistency and schema validation is maintained, of course).

It's also important to note that Codd's description of normalization focuses on the logical structure and the API, not the physical storage:

remember we are not discussing the physical representation

Data model to process data

Some critiques of the document model proposed by MongoDB sometimes mention Codd's relational theory as if the document model were heretical to established norms. It's important to clarify that physically storing nested structures doesn't violate the principles of normalized logical structures.
For modern applications, a document model API can be the best fit, just as highly normalized structures were once ideal for supporting casual users' ad-hoc queries. Both models serve different needs, and understanding this flexibility is crucial for leveraging the right approach in modern database applications.

Representing data as a set of independent tables makes it easy to display, but how do we efficiently process it, given the absence of navigable pointers and procedural languages?
To address this challenge, Codd introduced relational algebra, with powerful set-based operations such as projection (ρ), selection(σ), join (⋈), union (∪), intersection (∩), difference (−), product (×), and division (÷):

Now, it may be contended that tables are inadequate data structures to support facile manipulation of relationships between and within the tables. Application of elementary operations on relations (operations such as projection, join, and division) shows that this contention is false.

SQL is widely recognized as the declarative, English-based language that implements the operations defined by Codd's relational algebra, designed primarily for human users to interact with databases. However, the same operations can be achieved using MongoDB's aggregation pipelines on documents.

Notably, one operation, relational division — cited as essential for efficient data processing on normalized tables — can be quite complex to achieve in SQL databases but is more straightforward in MongoDB.

Relational Division

Relational division is essential for identifying relationships between tables based on subsets instead of individual rows. It finds records linked to every item in a specific subset. Practical business examples include:

  • Finding employees who possess all required certifications.
  • Identifying customers who purchase all items in a bundle.
  • Locating students who have completed all required courses.
  • Determining vendors supplying all contract materials.
  • Discovering authors collaborating with all team members.
  • Selecting athletes participating in all league events.
  • Finding tutors who cover every curriculum topic.
  • Identifying devices compatible with all software platforms.
  • Find the pilots who can fly all planes in the hangar

This operation is vital for scenarios where comprehensive coverage or participation across a set of criteria is necessary, and while complex in SQL, it's more straightforward to implement in MongoDB.

Relational Division in SQL (normalized - 3NF)

The pilots who can fly all planes in the hangar is an example taken from the excellent article Divided We Stand: The SQL of Relational Division by Joe Celko (Redgate).

In PostgreSQL, the following normalized tables can store pilots and planes entities, as well as the relations for planes in hangar and pilot skills:

CREATE TABLE pilots (
    pilot_id SERIAL PRIMARY KEY,
    pilot_name VARCHAR NOT NULL
);

CREATE TABLE planes (
    plane_id SERIAL PRIMARY KEY,
    plane_name VARCHAR NOT NULL
);

CREATE TABLE pilot_skills (
    pilot_id INT REFERENCES pilots(pilot_id),
    plane_id INT REFERENCES planes(plane_id),
    PRIMARY KEY (pilot_id, plane_id)
);

CREATE TABLE hangar (
    plane_id INT PRIMARY KEY REFERENCES planes(plane_id)
);
Enter fullscreen mode Exit fullscreen mode

I insert the same data as in the Redgate article:

INSERT INTO pilots (pilot_name) VALUES
    ('Celko'),
    ('Higgins'),
    ('Jones'),
    ('Smith'),
    ('Wilson')
;

INSERT INTO planes (plane_name) VALUES
    ('Piper Cub'),
    ('B-1 Bomber'),
    ('B-52 Bomber'),
    ('F-14 Fighter'),
    ('F-17 Fighter')
;

INSERT INTO pilot_skills (pilot_id, plane_id) VALUES
    (1, 1), -- Celko: Piper Cub
    (2, 3), (2, 4), (2, 1), -- Higgins: B-52 Bomber, F-14 Fighter, Piper Cub
    (3, 3), (3, 4), -- Jones: B-52 Bomber, F-14 Fighter
    (4, 2), (4, 3), (4, 4), -- Smith: B-1 Bomber, B-52 Bomber, F-14 Fighter
    (5, 2), (5, 3), (5, 4), (5, 5)  -- Wilson: B-1 Bomber, B-52 Bomber, F-14 Fighter, F-17 Fighter
;

INSERT INTO hangar (plane_id) VALUES
    (2), -- B-1 Bomber
    (3), -- B-52 Bomber
    (4)  -- F-14 Fighter
;
Enter fullscreen mode Exit fullscreen mode

To find pilots who can fly all planes in the hangar, use a double negation: identify all pilots for whom no plane in the hangar exists that they cannot fly. This corresponds to a double NOT EXISTS in SQL:

postgres=> SELECT p.pilot_id, p.pilot_name
FROM pilots p
WHERE NOT EXISTS (
    SELECT *
    FROM hangar h
    WHERE NOT EXISTS (
        SELECT *
        FROM pilot_skills ps
        WHERE ps.pilot_id = p.pilot_id AND ps.plane_id = h.plane_id
    )
);

 pilot_id | pilot_name 
----------+------------
        4 | Smith
        5 | Wilson
(2 rows)
Enter fullscreen mode Exit fullscreen mode

If you find it more readable, the second negation can be declared with EXCEPT or MINUS instead of NOT EXISTS:

postgres=> SELECT p.pilot_id, p.pilot_name
FROM pilots p
WHERE NOT EXISTS (
    SELECT plane_id FROM hangar
    EXCEPT
    SELECT plane_id FROM pilot_skills ps WHERE ps.pilot_id = p.pilot_id
);

 pilot_id | pilot_name
----------+------------
        4 | Smith
        5 | Wilson
(2 rows)

Enter fullscreen mode Exit fullscreen mode

If you feel more like an accountant than a logician, you can bypass SQL's lack of relational division by counting pilot skills and comparing them to the number of planes in the hangar:

postgres=> SELECT p.pilot_id, p.pilot_name
FROM pilots p
JOIN pilot_skills ps ON p.pilot_id = ps.pilot_id
JOIN hangar h ON ps.plane_id = h.plane_id
GROUP BY p.pilot_id, p.pilot_name
HAVING COUNT(DISTINCT h.plane_id) = (SELECT COUNT(*) FROM hangar);

 pilot_id | pilot_name 
----------+------------
        4 | Smith
        5 | Wilson
(2 rows)
Enter fullscreen mode Exit fullscreen mode

In mathematics, relational division may have a remainder. How can you list pilots with additional skills (planes they can fly that are not in the hangar)? How would you identify pilots lacking required skills and specify the missing skills?

E. F. Codd stated that processing normalized tables would not be difficult due to relational operations, but what happens if no SQL database implements them? A document model may be easier.

Relational Division in SQL (unnormalized - 0NF)

Let's violate the first normal form and store the skills as an array (which is a PostgreSQL datatype) embedded with the pilot:

CREATE TABLE pilotsWithSkills (
    pilot_name VARCHAR PRIMARY KEY,
    planes VARCHAR[] -- An array of plane names
);

INSERT INTO pilotsWithSkills (pilot_name, planes)
VALUES
 ('Celko', ARRAY['Piper Cub']),
 ('Higgins', ARRAY['B-52 Bomber', 'F-14 Fighter', 'Piper Cub']),  
 ('Jones', ARRAY['B-52 Bomber', 'F-14 Fighter']),
 ('Smith', ARRAY['B-1 Bomber', 'B-52 Bomber', 'F-14 Fighter']),
 ('Wilson', ARRAY['B-1 Bomber', 'B-52 Bomber', 'F-14 Fighter', 'F-17 Fighter']);

Enter fullscreen mode Exit fullscreen mode

I can use the <@ operator with a subquery to find the pilots who can fly all planes in the hangar:

SELECT pilot_name
FROM pilotsWithSkills
WHERE array(
   select plane_name from hangar join planes using (plane_id)
) <@ planes
;
Enter fullscreen mode Exit fullscreen mode

With a GIN index on the array, the following execution plan with Bitmap Index Scan and Recheck Cond can optimize the search:
Image description

I can also create the list in JSONB instead of ARRAY and use jsonb_agg() instead of array(). But another possibility is to use a document database.

Relational Division in MongoDB

To normalize without the complexity of embedding arrays or JSON in SQL tables, MongoDB can store and index documents natively:

db.pilotSkills.insertMany([
  { pilot_name: 'Celko', planes: ['Piper Cub'] },
  { pilot_name: 'Higgins', planes: ['B-52 Bomber', 'F-14 Fighter', 'Piper Cub'] },
  { pilot_name: 'Jones', planes: ['B-52 Bomber', 'F-14 Fighter'] },
  { pilot_name: 'Smith', planes: ['B-1 Bomber', 'B-52 Bomber', 'F-14 Fighter'] },
  { pilot_name: 'Wilson', planes: ['B-1 Bomber', 'B-52 Bomber', 'F-14 Fighter', 'F-17 Fighter'] }
]);

db.hangar.insertMany([
  { plane_name: 'B-1 Bomber' },
  { plane_name: 'B-52 Bomber' },
  { plane_name: 'F-14 Fighter' }
]);

db.pilotSkills.createIndex({ planes: 1 });

Enter fullscreen mode Exit fullscreen mode

Here is how I find the pilots who can fly all planes in the hangar:

mdb> db.pilotSkills.find({
      planes: { $all: db.hangar.distinct("plane_name") }
    } , { pilot_name: 1, _id: 0})
;

[ { pilot_name: 'Smith' }, { pilot_name: 'Wilson' } ]

Enter fullscreen mode Exit fullscreen mode

If you look at the execution plan (adding .explain()) you will see that the MongoDB Multi-Plan optimizer has considered using the index for one of each value, in case one is more selective, or the combination of the three with an AND_SORTED

It is possible to do it in one query, and even a more complex query, like adding the extra skills of the pilot (the planes not in the hangar) for a relational division with reminder:

db.pilotSkills.aggregate([
  // Lookup hangar data to include required planes
  {
    $lookup: {
      from: "hangar",
      pipeline: [
        { $group: { _id: null, plane_names: { $addToSet: "$plane_name" } } }
      ],
      as: "hangar_planes"
    }
  },
  // Unwind the hangar_planes array
  {
    $unwind: "$hangar_planes"
  },
  // Match pilots who can fly all planes in the hangar
  {
    $match: {
      $expr: {
        $setIsSubset: ["$hangar_planes.plane_names", "$planes"]
      }
    }
  },
  // Add a field for extra skills beyond the required planes
  {
    $addFields: {
      extraSkills: {
        $filter: {
          input: "$planes",
          as: "plane",
          cond: { $not: { $in: ["$$plane", "$hangar_planes.plane_names"] } }
        }
      }
    }
  },
  // Project only the desired fields
  {
    $project: {
      pilot_name: 1,
      extraSkills: 1,
      _id: 0
    }
  }
]);

[
  { pilot_name: 'Smith', extraSkills: [] },
  { pilot_name: 'Wilson', extraSkills: [ 'F-17 Fighter' ] }
]

Enter fullscreen mode Exit fullscreen mode

With $setIsSubset MongoDB implements relational division with better developer experience than SQL's subqueries with double negations or counting. PostgreSQL JSONB adds operations on documents, but can become more complex, for example for the division with remainder. MongoDB simplifies this through a series of steps in an aggregation pipeline: retrieving planes from the hangar, unwinding into an array to compare to the pilot's array of skills, applying division logic between the two, calculating the remainders, and projecting pilot names with skills.

It may be surprising, but SQL must use complex subqueries, while MongoDB provides a direct method for this relational algebra operator, enabling efficient processing of normalized collections.

Top comments (0)

👋 Kindness is contagious

If this post resonated with you, feel free to hit ❤️ or leave a quick comment to share your thoughts!

Okay