Selecting all Columns Except One in PostgreSQL

Google’s BigQuery has a very interesting SQL language feature, which I’ve missed many times in other databases:

select:
    SELECT  [{ ALL | DISTINCT }]
        { [ expression. ]* [ EXCEPT ( column_name [, ...] ) ]
            [ REPLACE ( expression [ AS ] column_name [, ...] ) ]
        | expression [ [ AS ] alias ] } [, ...]
    [ FROM from_item  [, ...] ]
    [ WHERE bool_expression ]
    ...

Notice the two keywords EXCEPT and REPLACE that can be used along with an asterisked expression.

An Example

For example, when running a query like this one (which fetches the longest film(s) every actor in the Sakila database played in):

SELECT *
FROM (
  SELECT 
    a.*, 
    f.*, 
    RANK() OVER (PARTITION BY actor_id ORDER BY length DESC) rk
  FROM film f
  JOIN film_actor fa USING (film_id)
  JOIN actor a USING (actor_id)
) t
WHERE rk = 1
ORDER BY first_name, last_name

This is one way to apply TOP-N per category filtering in SQL, which works with most modern databases, including MySQL 8.0. Essentially, we’re calculating the rank of a film per actor ordered by the film’s length.

The result looks like this:

actor_id |first_name  |last_name    |..|title                  |length|..|rk |
---------|------------|-------------|..|-----------------------|------|--|---|
71       |ADAM        |GRANT        |..|GLADIATOR WESTWARD     |   173|..|1  |
71       |ADAM        |GRANT        |..|BALLROOM MOCKINGBIRD   |   173|..|1  |
132      |ADAM        |HOPPER       |..|TORQUE BOUND           |   179|..|1  |
165      |AL          |GARLAND      |..|JACKET FRISCO          |   181|..|1  |

Let’s assume for a moment that we really need the entire projection of the ACTOR and FILM tables (so, SELECT * is fine), but we certainly don’t need the useless RK column, which is always 1.

Sometimes, having some excess columns is not going to be a problem, but sometimes it is. How to remove it? We can’t reference the ACTOR and FILM tables anymore in the outer query:

SELECT a.*, f.* -- Would be great, but wrong syntax
FROM (
  SELECT 
    a.*, 
    f.*, 
    RANK() OVER (PARTITION BY actor_id ORDER BY length DESC) rk
  FROM film f
  JOIN film_actor fa USING (film_id)
  JOIN actor a USING (actor_id)
) t
WHERE rk = 1
ORDER BY first_name, last_name

The outer query only has one table, and that’s the (derived) table T.

How to Solve This

In BigQuery syntax, we could now simply write

SELECT * EXCEPT rk
FROM (...) t
WHERE rk = 1
ORDER BY first_name, last_name

Which is really quite convenient! We want to project everything, except this one column. But none of the more popular SQL databases support this syntax.

Luckily, in PostgreSQL, we can use a workaround: Nested records:

SELECT (a).*, (f).* -- Unnesting the records again
FROM (
  SELECT 
    a, -- Nesting the actor table
    f, -- Nesting the film table
    RANK() OVER (PARTITION BY actor_id ORDER BY length DESC) rk
  FROM film f
  JOIN film_actor fa USING (film_id)
  JOIN actor a USING (actor_id)
) t
WHERE rk = 1
ORDER BY (a).first_name, (a).last_name;

Notice how we’re no longer projecting A.* and F.* inside of the derived table T, but instead, the entire table (record). In the outer query, we have to use some slightly different syntax to unnest the record again (e.g. (A).FIRST_NAME), and we’re done.

How Does This Work?

Informix, Oracle, PostgreSQL, and maybe a few lesser known ones, have implemented the SQL standard’s ORDBMS features to various degrees. ORDBMS attempted to combine relational and object oriented features in the SQL language (and in the storage model). For all practical purposes, this essentially just means that we can nest records and collections.

For instance, in PostgreSQL, we can write:

-- Explicit ROW constructor
SELECT 1, ROW(2, ROW(3, 4))

-- Implicit ROW constructor
SELECT 1, (2, (3, 4))

And we’ll get:

x        |row       |
---------|----------|
1        |(2,(3,4)) |

Along with ordinary “scalar” values, we can have nested rows (or nested tuples) constructed very easily. Conveniently, we can also reference a table without its column names in the projection, such as:

SELECT a, f
FROM film f
JOIN film_actor fa USING (film_id)
JOIN actor a USING (actor_id)

Which produces the aforementioned result:

a    |f    |
-----|-----|
(...)|(...)|
(...)|(...)|
(...)|(...)|
...

Similar things are possible in Oracle as well, except that Oracle doesn’t support structural row/tuple types, only nominal ones. We’d have to create some types first, prior to being able to use them:

CREATE TABLE film_t AS OBJECT (...);

Bonus

Of course, if you’re using SQL Server or Oracle, you wouldn’t have this problem, because then you could use the totally underrated WITH TIES clause along with CROSS APPLY:

SQL Server

SELECT *
FROM actor a
CROSS APPLY (
  SELECT TOP 1 WITH TIES f.*
  FROM film f
  JOIN film_actor fa 
    ON f.film_id = fa.film_id
	AND fa.actor_id = a.actor_id
  ORDER BY length DESC
) f
ORDER BY first_name, last_name;

Oracle

(Do check performance on this!)

SELECT *
FROM actor a
CROSS APPLY (
  SELECT f.*
  FROM film f
  JOIN film_actor fa 
    ON f.film_id = fa.film_id
	AND fa.actor_id = a.actor_id
  ORDER BY length DESC
  FETCH FIRST ROW WITH TIES
) f
ORDER BY first_name, last_name;

PostgreSQL and DB2 support the LATERAL keyword, which could be used with FETCH FIRST ROW ONLY semantics (so, no ties are selected).

For more details about TOP N per category queries, see this blog post

jOOQ Newsletter: January 21, 2015 – Groovy and Open Source – jOOQ and the strong Swiss Franc

Subscribe to this newsletter here

Tweet of the Day

Today, we’re very happy to have “spied” on our users as we can now show you a whole Tweet Conversation of the Day

RxJooq, or reactive jOOQ. How does that sound!? Yes, jOOQ is growing to become a hype among SQL and fluent API aficionados. A recent discussion on reddit already puts jOOQ on the same level with Hibernate with more than 10 mentions in answers to the question “Java: What ORM to use”. Our goal has always been for a Java developer to ask themselves at the beginning of a project:

Is this a jOOQ project, or is this a Hibernate project (or both)?

It is too early to announce anything, but at Data Geekery, we’re very interested and thus putting efforts into collaborating with Red Hat to make the jOOQ / Hibernate integration work more seamlessly, so stay tuned for more goodness in that area.

Groovy and Open Source – What it means for us

You may have heard of Pivotal’s recent announcement about their withdrawing sponsorship from the Groovy and Grails ecosystem. This isn’t exactly a surprise to many people as Pivotal’s main focus has shifted towards their PaaS business quite some time ago. The interesting aspect from our perspective is the fact that a whole ecosystem seems to have relied on the benevolence of a single sponsor. Quite a risk!

We think that Open Source should work differently. Open Source is a fine means of offering freemium and (legally) riskless software to potential customers in order to help customers start engaging with a brand. The ultimate vendor goal with Open Source is always upselling. As our valued jOOQ users and jOOQ newsletter and blog readers, we obviously hope that you will eventually understand all the combined SQL value put into jOOQ, and thus upgrade to a commercial jOOQ subscription.

This wasn’t necessarily the case at Pivotal. There is no obvious path from using Groovy (or Grails) to buying Pivotal’s cloud platform solutions. To make things worse, in order to survive, the Groovy platform now depends on a new, arbitrary sponsor whose incentive to sponsor Groovy might be 100% different from Pivotal’s. For the end user, this will not be the same Groovy any more – so it is hard to believe that Groovy will not suffer heavily from any future transition.

We believe that vendors shouldn’t depend on benevolence. We believe that vendors should have a very clear strategy why they’re creating a product, and do everything necessary to satisfy real customer’s needs. So we want to take the opportunity and thank you for being with us, and for making jOOQ (both the Open Source Edition and the Commercial Editions) what it is: A platform valued by both users of Open Source and commercial databases.

More information about our take on Pivotal and Groovy can be found on our blog:

It’s jOONuary! Profit from our 20% Discount Promotion

Speaking of our customers, there has never been a better time to become one!

Your budget for 2015 has been set in stone? You spent too much money on geeky infrastructure during the Holiday Season? Not a problem for your planned jOOQ integration! If you purchase new jOOQ licenses in jOONuary (January 2015), we will offer you a limited-time 20% discount on all price plans. Act quickly!

http://www.jooq.org/joonuary

jOOQ and the Strong Swiss Franc

We’re a Switzerland-based company, and as such are heavily influenced by recent events on the currency exchange markets. The EUR (which is our sale currency) has plummeted almost 20% compared to the CHF (which is our accounting currency).

This affects all of the Swiss export industry, and many companies are starting to take measures. We will not take any measures thus far and continue with our existing EUR-based price model. For our international customers, nothing will change. For our Swiss customers, this means that in addition to the above jOONuary discount, you will now also benefit from a “Euro discount”! Did we say there has never been a better time to become our customer?

jOOQ 3.6 Outlook

The upcoming jOOQ 3.6 will not be less exciting than the previous versions in the least bit. Here is a quick outline of what we’re going to be doing in the upcoming release:

  • SAP HANA support. We’ve been talking to database vendors in the past, and we continue to do so, maintaining good relationships with the technical and community people at the vendor side. This time, the collaboration initiative came from the vendor directly, and we’ve heard them.

    SAP HANA is an emerging cloud SQL and in-memory SQL platform, with a big Java and Scala based tool chain, which constitutes a perfect match for the jOOQ ecosystem. We’re going to support both HANA’s SQL features as well as HANA’s SQLScript features in the jOOQ 3.6 Enterprise Edition. If you’re an SAP HANA user and interested in details, or in a free preview of jOOQ 3.6.0, please contact sales right away. We’re more than happy to provide you with more info.

  • Nested records and tables. One of the SQL standard’s most underestimated features is the capability of nesting records and tables. In a true ORDBMS, tables (or MULTISETs) can be nested any level deep. If your SQL database supports these features, it is very easy to materialise a nested object graph directly in the database, instead of relying on the JOIN-based workarounds provided by modern ORMs.

    Nesting of records can also be very useful when reusing common data structures, such as audit columns (creation_date, creation_user, modification_date, modification_user). JPA supports the @Embedded annotation for this, and we’ll delve into these features as well.

    We believe that true MULTISET support will obsolete our competing products’ most important asset: mapping. Once you can declare all mapping already in SQL, you will no longer miss JPA once you’ve migrated to jOOQ.

  • A new ConverterProvider SPI. Converters are great for supporting custom data types, but having to register them all the time is tedious. What if jOOQ just supported T <-> U conversion right out of the box, for any combination of T and U? We’ll let you register all your favourite converters and jOOQ figures out the conversion path through the converter graph.
  • Even better PL/SQL support. PL/SQL types are ubiquitous, but they are not easily accessible via JDBC, and thus via jOOQ. We’re researching a variety of possibilities of working around JDBC’s limitations to allow you to use your favourite PL/SQL types: BOOLEAN, RECORD types, perhaps even table types.

 

Upcoming jOOQ Events

Have you missed one of our talks and presentations in the recent past? No problem at all, we’re back on the road after a short winter break. Here are all of our upcoming events:

Keep up to date with our own and third-party jOOQ events on our news website:http://www.jooq.org/news.

We’re looking forward to meeting you and to talking about all things Java and SQL!