For software projects I work with various relational database management systems (RDBMs), mainly PostgreSQL, MySQL/MariaDB, Oracle Database and Microsoft SQL Server. All of these use SQL as a query language, but the dialects of this language vary wildly, especially when it comes to non-standardized features. One such feature I often use is the aggregation of a list to a string. It does the following.
LEGS ANIMAL
-----------------
2 Ostrich
2 Human
4 Cat
4 Dog
4 Capybara
6 Ant
8 Spider
Given a table like the one above it groups the elements of a column that have the same value in another column together in a string, concatenated by a separator like a comma:
LEGS ANIMALS
----------------------------
2 Human, Ostrich
4 Capybara, Cat, Dog
6 Ant
8 Spider
This simple operation has four different syntaxes in the four mentioned database systems, which I want to demonstrate.
PostgreSQL
In PostgreSQL the function is called STRING_AGG
:
SELECT legs,
STRING_AGG(animal, ', ' ORDER BY animal) AS animals
FROM fauna
GROUP BY legs
ORDER BY legs;
MySQL / MariaDB
In MySQL and its fork MariaDB the function is called GROUP_CONCAT
, and it has a special syntax to specify the separator:
SELECT legs,
GROUP_CONCAT(animal ORDER BY animal SEPARATOR ', ') AS animals
FROM fauna
GROUP BY legs
ORDER BY legs;
Oracle
Oracle calls it LISTAGG
and specifies the grouping via WITHIN GROUP
.
SELECT legs,
LISTAGG(animal, ', ') WITHIN GROUP (ORDER BY animal) AS animals
FROM fauna
GROUP BY legs
ORDER BY legs;
Microsoft SQL Server
SQL Server calls it STRING_AGG
like PostgreSQL, but specifies the grouping via WITHIN GROUP
like Oracle:
SELECT legs,
STRING_AGG(animal, ', ') WITHIN GROUP (ORDER BY animal) AS animals
FROM fauna
GROUP BY legs
ORDER BY legs;
Unfortunately, as developers we have to live with all these dialects of SQL. Even though there is an ISO standards committee for SQL, database creators love to build non-standard extensions into their products. The situation is worse than the browser-specific extensions and differences of JavaScript, HTML and CSS in modern web browsers. One thing that can paper over these differences are OR-Mappers like Hibernate or query languages like Hibernate’s HQL that abstract over SQL, but they come with their own set of problems.