aboutsummaryrefslogtreecommitdiff
path: root/dbstore/sql/cpe/search-ref.sql
blob: a2d3be6050558ffabff2d4a6050f175f758df7cb (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
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 (
    -- there can be multiple matching references for a given
    -- CPE, so use MIN() to limit the match to the most
    -- "relevant", according to bm25()
    SELECT cpe_id,
           MIN(rank) AS rank
      FROM cpe_fts_refs
     WHERE cpe_fts_refs 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