aboutsummaryrefslogtreecommitdiff
path: root/dbstore/sql/old-cpe-search-all.sql
blob: 18e286f28fa127609ac281113560a4433a8b3cf5 (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
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
SELECT a.cpe_id,
       a.cpe23,
       COALESCE(c.titles, '[]') AS titles,
       COALESCE(d.refs, '[]') AS refs,
       b.rank

  FROM cpes a
  JOIN (
    -- limit to "best" match (e.g., lowest rank) for given CPE
    -- NOTE: it's not clear to me whether cross-index bm25()
    -- comparisons are valid
    SELECT a.cpe_id,
           MIN(a.rank) AS rank

      FROM (
        -- find title matches
        SELECT b.cpe_id,
               a.rank AS rank

          FROM cpe_titles_fts a
          JOIN cpe_titles b
            ON (b.cpe_title_id = a.rowid)

         WHERE cpe_titles_fts MATCH :q

        UNION ALL

        -- find reference matches
        SELECT b.cpe_id,
               a.rank

          FROM cpe_refs_fts a
          JOIN cpe_refs b
            ON (b.cpe_ref_id = a.rowid)

         WHERE cpe_refs_fts MATCH :q
      ) a

     GROUP BY a.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