There is no Such Thing as Object-Relational Impedance Mismatch
Much of the ORM criticism of the last decade missed the point, being inaccurate. By the end of this article, we will conclude with the following:
There is no significant difference between the relational (data) model and object oriented models
How to come to this conclusion? Read on!
How we came to believe in this fallacy
Many popular bloggers and opinion leaders have missed no chance to bash ORMs for their “obvious” impedance mismatch with the relational world. N+1, inefficient queries, library complexity, leaky abstractions, all sorts of buzzwords have been employed to dismiss ORMs – often containing a lot of truth, albeit without providing a viable alternative.
But are these articles really criticising the right thing?
Few of the above articles recognise a central fact, which has been elicited eloquently and humorously by Erik Meijer and Gavin Bierman in his very interesting paper “A co-Relational Model of Data for Large Shared Data Banks“, subtitled:
Contrary to popular belief, SQL and noSQL are really just two sides of the same coin.
Or in other words: The “hierarchical” object world and the “relational” database world model the exact same thing. The only difference is the direction of the arrows that you draw in your diagrams.
Let this sink in.
- In the relational model, children point to their parent.
- In the hierarchical model, parents point to their children.
That’s all there is to it.
What is an ORM?
ORMs fill the bridge between the two worlds. They’re the inverters of arrows, if you will. They will make sure that every “relation” in your RDBMS can be materialised as an “aggregation” or “composition” in your “hierarchical” world (this works for objects, XML, JSON, and any other format). They make sure that such materialisation is properly transacted. That changes to individual attributes or to relational (aggregational, compositional) attributes are properly tracked and purged back into the master model, the database – where the model is persisted. Individual ORMs differ in terms of offered features and in how much mapping logic they offer in addition to mapping individual entities to individual types.
- Some ORMs may help you implement locking
- Some may help you to patch model mismatches
- Some may focus merely on a 1:1 mapping between these classes and tables
But all ORMs do one very simple thing. Ultimately, they take rows from your tables and materialise them as objects in your class model and vice-versa.
A very nice overview of different ORMs has been compiled on the Vertabelo blog, recently, by the way.
Tables and classes are the same thing
Give or take 1-2 implementation details, an RDBMS’s table and an OO language’s class is the same thing. A specification of a set of grouped attributes, each with their associated type. Consider the following example, using SQL and Java:
SQL
CREATE TABLE author ( first_name VARCHAR(50), last_name VARCHAR(50) );
Java
class Author { String firstName; String lastName; }
There is absolutely no conceptual difference between the two – the mapping is straightforward. The mapping is even straightforward when you consider “relations” / “compositions” between different entities / types:
SQL (let’s leave away constraints for simplicity)
CREATE TABLE author ( id BIGINT, first_name VARCHAR(50), last_name VARCHAR(50) ); CREATE TABLE book ( id BIGINT, author_id BIGINT, title VARCHAR(50), );
Java
class Author { Long id; String firstName; String lastName; Set<Book> books; } class Book { Long id; Author author; String title; }
The implementation details are omitted (and probably account for half of the criticism). But omitting further details allows for straight-forward 1:1 mapping of individual rows from your database to your Java model, without any surprises. Most ORMs – in the Java ecosystem Hibernate in particular – have managed to implement the above idea very well, hiding away all the technical details of actually doing such a model transfer between the RDBMS and Java.
In other words:
There is absolutely nothing wrong with this mapping approach!
Yet: There *IS* an impedance mismatch, somewhere
The “problems” that many bloggers criticise arise not from the non-existing mismatch between the two model representations (“relational” vs. “hierarchical”). The problems arise from SQL, which is a decent implementation of relational algebra.
In fact, the very same mismatch that everyone criticises is also present between:
Relational algebra has been defined in order to be able to query relations and to form new ad-hoc relations as an output of such queries. Depending on the operations and transformations that are applied, the resulting tuples may have absolutely nothing to do with the individual entities involved in a query. In other, ORM-y words: The product of relational algebra, and in particular of SQL has no use, as it can no longer be further processed by the ORM, let alone persisted back into the database.
To make things “worse”, SQL today is a large super-set of the features offered by relational algebra. It has gotten much more useful than when it was conceived.
Why this mismatch still affects modern ORMs
The previous paragraphs outlined the single main reason why ORMs are really criticised, even if such criticism often doesn’t mention this exact reason:
SQL / relational algebra is not really appropriate to partially materialise relations into a client / store changes back into the database. Yet, most RDBMS offer only SQL for that job.
Back to the author / book example. When you want to load and display an author and their books to a web application’s user, you’d like to simply fetch that author and their books, call simple methods like author.add(book)
as well as author.remove(book)
and let some magic flush your data back into the storage system.
Thinking about the amount of SQL code to be written for such a simple CRUD task makes everyone squeal.
Life’s too short to spend time on CRUD
Perhaps QUEL might have been a better language for CRUD, but that ship has sailed. And unfortunately, because of SQL being an inappropriate language for this job, you cannot ignore that “magic” but have to know well what happens behind the scenes, e.g. by tweaking Hibernate’s fetching strategies.
Translated to SQL, this may be implemented in several ways:
1. Fetching with JOIN
Using outer joins, all the involved entities can be queried in one go:
SELECT author.*, book.* FROM author LEFT JOIN book ON author.id = book.author_id WHERE author.id = ?
Advantages:
- A single query can be issued and all the data can be transferred at once
Disadvantages:
- The author attributes are repeated in every tuple. The client (ORM) has to de-duplicate authors first, before populating the author-book relationship. This can be particularly bad when you have many nested relations that should be fetched at once.
2. Fetching with SELECT
A single query is issued for each entity:
SELECT * FROM author WHERE id = ? SELECT * FROM book WHERE author_id = ?
Advantages:
- The amount of data to be transferred is minimal: Each row is transferred exactly once.
Disadvantages:
- The amount of queries that are issued may explode into the well-known N+1 problem.
Hibernate in particular knows other types of fetch strategies, although they are essentially a variant / optimisation of one of the above.
Why not use SQL MULTISET?
The ideal way to fetch all data in this case using advanced SQL would be by using MULTISET
:
SELECT author.*, MULTISET ( SELECT book.* FROM book WHERE book.author_id = author.id ) AS books FROM author WHERE id = ?
The above will essentially create a nested collection for each author:
first_name last_name books (nested collection) -------------------------------------------------- Leonard Cohen title -------------------------- Book of Mercy Stranger Music Book of Longing Ernest Hemingway title -------------------------- For Whom the Bell Tolls The Old Man and the Sea
If you add another nested entity, it is easy to see how another MULTISET
could allow for additionally nested data:
SELECT author.*, MULTISET ( SELECT book.*, MULTISET ( SELECT c.* FROM language AS t JOIN book_language AS bl ON c.id = bc.language_id AND book.id = bc.book_id ) AS languages FROM book WHERE book.author_id = author.id ) AS books FROM author WHERE id = ?
The outcome would now be along the lines of:
first_name last_name books ----------------------------------------------------- Leonard Cohen title languages ----------------------------- Book of Mercy language ------------ en Stranger Music language ------------ en de Book of Longing language ------------ en fr es
Advantages:
- A single query can materialise all eager-loaded rows with minimal bandwidth usage.
Disadvantages:
- None.
Unfortunately, MULTISET is poorly supported by RDBMS.
MULTISET
(as well as arrays and other collection types) have been introduced formally into the SQL standard as of SQL:2003, as a part of an initiative to embed OO features into the SQL language. Oracle, for instance, has implemented much of it, much like Informix did, or the lesser-known CUBRID (although using vendor-specific syntax).
Other databases like PostgreSQL allow for aggregating nested rows into typed arrays, which works the same way although with a bit more syntactic effort.
MULTISET
and other ORDBMS SQL features are the perfect compromise, allowing for combining the best of the “relational” model with the best of the “hierarchical” model. Allowing for combining CRUD operations with querying in one go, removing the need for sophisticated ORMs, as the SQL language can be used directly to map all your data from your (relational) database to your (hierarchical) client representation with no friction.
Conclusion and call to action!
We’re living through exciting times in our industry. The elephant (SQL) in the room is still here, learning new tricks all the time. The relational model has served us well, and has been enriched with hierarchical models in various implementations. Functional programming is gaining traction, complementing object orientation in very useful ways.
Think of the glue, putting all these great technological concepts together, allowing for:
- Storing data in the relational model
- Materialising data in the hierarchical model
- Processing data using functional programming
That awesome combination of techniques is hard to beat – we’ve shown how SQL and functional programming can work with jOOQ. All that’s missing – in our opinion – is better support for MULTISET
and other ORDBMS features from RDBMS vendors.
Thus, we urge you, PostgreSQL developers: You’re creating one of the most innovative databases out there. Oracle is ahead of you in this area – but their implementation is too strongly tied to PL/SQL, which makes it clumsy. Yet, you’re missing out on one of the most awesome SQL feature sets. The ability to construct nested collections (not just arrays), and to query them efficiently. If you lead the way, other RDBMS will follow.
And we can finally stop wasting time talking about the object-relational impedance non-mismatch.
Reference: | There is no Such Thing as Object-Relational Impedance Mismatch from our JCG partner Lukas Eder at the JAVA, SQL, AND JOOQ blog. |
ORM is a misnomer. Objects are not only data carriers. Within a java stack, a name which would be more accurate would be POJO RM.
And even that won’t be highly coherent.
Well, Relations (in some implementations) aren’t only data carriers either. ORDBMS have extended the relational model by modelling rows as object instances as well