In my rails app (using postgresql), I'm trying to compose an Active Record query to find a group of volunteer records and then order them by first_name
, then last_name
, then email
. Additionally, first_name
and last_name
may be null
(either both will be null
or both will be not null
). For example, I would want to following list to be sorted thusly:
- Volunteer [first_name: 'Alex', last_name: 'Diego', email: 'a.diego@person.com']
- Volunteer [first_name:
null
, last_name:null
, email: 'cxxr@person.com'] - Volunteer [first_name: 'Josh', last_name: 'Broger', email: 'broger@person.com']
- Volunteer [first_name: 'Josh', last_name: 'Broger', email: 'jcool@person.com']
- Volunteer [first_name: 'Josh', last_name: 'Kenton', email: 'aj@person.com']
Originally, I had the following code:
Volunteer.joins(:volunteer_lists).
where("(volunteer_lists.organizer_id = ? AND organizer_type = 'Organization') OR
(volunteer_lists.organizer_id IN (?) AND organizer_type = 'Collaborative')",
self.organization.id, collaboratives).uniq.
order(:first_name, :last_name, :email)
This code works except the results are grouped by volunteers with first_name
& last_name
first, other volunteers with only email
last (so in the example list above, volunteer #2 would be last). The answer to this helpful post indicates that I should use a COALESCE()
function in the ORDER BY
part of the statement to get the results I want. Awesome! So I updated my code to the following:
Volunteer.joins(:volunteer_lists).
where("(volunteer_lists.organizer_id = ? AND organizer_type = 'Organization') OR
(volunteer_lists.organizer_id IN (?) AND organizer_type = 'Collaborative')",
self.organization.id, collaboratives).uniq.
.order('COALESCE("volunteers"."first_name", "volunteers"."email") ASC, COALESCE("volunteers"."last_name", "volunteers"."email") ASC, "volunteers"."email" ASC')
The problem is that this code now returns
PG::InvalidColumnReference: ERROR: for SELECT DISTINCT, ORDER BY expressions must appear in select list
Using to_sql
on both versions of the code, I find they are exactly the same except for the addition of the COALESCE()
function.
to_sql
of original, working, code:
SELECT "organizations".* FROM "organizations" WHERE "organizations"."id" = $1 LIMIT 1 [["id", 1]]
=> "SELECT DISTINCT \"volunteers\".* FROM \"volunteers\" INNER JOIN \"volunteer_list_connectors\" ON \"volunteer_list_connectors\".\"volunteer_id\" = \"volunteers\".\"id\" INNER JOIN \"volunteer_lists\" ON \"volunteer_lists\".\"id\" = \"volunteer_list_connectors\".\"volunteer_list_id\" WHERE ((volunteer_lists.organizer_id = 1 AND organizer_type = 'Organization') OR\n (volunteer_lists.organizer_id IN (1) AND organizer_type = 'Collaborative')) ORDER BY \"volunteers\".\"first_name\" ASC, \"volunteers\".\"last_name\" ASC, \"volunteers\".\"email\" ASC"
to_sql
of updated code (the only difference is after ORDER BY
):
SELECT "organizations".* FROM "organizations" WHERE "organizations"."id" = $1 LIMIT 1 [["id", 1]]
=> "SELECT DISTINCT \"volunteers\".* FROM \"volunteers\" INNER JOIN \"volunteer_list_connectors\" ON \"volunteer_list_connectors\".\"volunteer_id\" = \"volunteers\".\"id\" INNER JOIN \"volunteer_lists\" ON \"volunteer_lists\".\"id\" = \"volunteer_list_connectors\".\"volunteer_list_id\" WHERE ((volunteer_lists.organizer_id = 1 AND organizer_type = 'Organization') OR\n (volunteer_lists.organizer_id IN (1) AND organizer_type = 'Collaborative')) ORDER BY COALESCE(\"volunteers\".\"first_name\", \"volunteers\".\"email\") ASC, COALESCE(\"volunteers\".\"last_name\", \"volunteers\".\"email\") ASC, \"volunteers\".\"email\" ASC"
I tested trying my new code without .uniq
(to remove the DISTINCT
part of the sql) and when I do this the new code runs without error, however the results are NOT sorted properly: they are sorted the same way as my original code is (the code without COALESCE()
).
I imagine that there is a syntax error that I've committed, but I can't figure out what it is (or perhaps I'm wrong and COALESCE()
is not the proper solution to my problem).
Any help is GREATLY appreciated!!
UPDATE & ANSWER
After getting invaluable help from Kristján and his answer below, I solved what turned out to be multiple problems:
- When you add
.uniq
to an ActiveRecord query, it addsDISTINCT
to the sql that gets sent to the database.SELECT DISTINCT
has some stricter requirements than simplySELECT
. As pointed out by Kristján and described in more detail in this S.O. answer, theDISTINCT
expression(s) must match the leftmostORDER BY
expression(s). When I updated.order()
with my sql fragment includingCOALESCE()
, I also needed to add a matching sql fragment to theSELECT
part of the statement with.select()
. - 1 above just removes the error I was getting. At that point, my query was running but the results were being sorted the same as they were before using
COALESCE()
. Kristján provides a proper description in his answer below, but turns out my query was running correctly, its just thatCOALESCE()
sorts anything uppercase before anything lowercase. so "Z" will be sorted in front of "a". This problem can be solved by adding a function to convert theCOALESCE()
fields to lowercase usingLOWER()
.
Here is my answer:
Volunteer.select('LOWER(COALESCE("volunteers"."first_name", "volunteers"."email")), LOWER(COALESCE("volunteers"."last_name", "volunteers"."email")), LOWER("volunteers"."email"), "volunteers".*').
joins(:volunteer_lists).
where("(volunteer_lists.organizer_id = ? AND organizer_type = 'Organization') OR
(volunteer_lists.organizer_id IN (?) AND organizer_type = 'Collaborative')",
self.organization.id, collaboratives).uniq.
order('LOWER(COALESCE("volunteers"."first_name", "volunteers"."email")) ASC, LOWER(COALESCE("volunteers"."last_name", "volunteers"."email")) ASC, LOWER("volunteers"."email") ASC')
Note:
My answer above actually created another problem when I later call .count
on the query. .count
breaks because of the custom .select()
fragment I've added. To solve this, I needed to add a custom volunteers_count
method to the User
model that didn't make use of the .select()
fragment.