SELECT a.cpe_id, a.cpe23, COALESCE(c.titles, '[]') AS titles, COALESCE(d.refs, '[]') AS refs, b.rank -- find matching cpes FROM cpes a JOIN ( SELECT cpe_id, MIN(rank) AS rank FROM cpe_fts_titles WHERE cpe_fts_titles MATCH :q GROUP BY cpe_id ) b ON (b.cpe_id = a.cpe_id) -- get all titles, grouped by cpe LEFT JOIN ( SELECT cpe_id, json_group_array(json_object( 'lang', lang, 'text', val )) AS titles FROM cpe_titles GROUP BY cpe_id ) c ON (c.cpe_id = b.cpe_id) -- get all refs, grouped by cpe LEFT JOIN ( SELECT cpe_id, json_group_array(json_object( 'href', href, 'text', val )) AS refs FROM cpe_refs GROUP BY cpe_id ) d ON (d.cpe_id = b.cpe_id) -- order by rank ORDER BY b.rank;