88 lines
2.0 KiB
SQL
88 lines
2.0 KiB
SQL
WITH uma_names AS (
|
|
SELECT
|
|
"index" AS "id",
|
|
"text" AS "name"
|
|
FROM text_data
|
|
WHERE category = 6 AND "index" BETWEEN 1000 AND 1999
|
|
-- Exclude characters who have no succession relations defined.
|
|
AND "index" IN (SELECT chara_id FROM succession_relation_member)
|
|
), trios AS (
|
|
SELECT
|
|
a.id AS id_a,
|
|
a.name AS name_a,
|
|
b.id AS id_b,
|
|
b.name AS name_b,
|
|
c.id AS id_c,
|
|
c.name AS name_c
|
|
FROM uma_names a
|
|
JOIN uma_names b ON a.id != b.id -- exclude pairwise reflexive cases
|
|
JOIN uma_names c ON a.id != c.id AND b.id != c.id
|
|
), relation_trios AS (
|
|
SELECT
|
|
ra.relation_type,
|
|
ra.chara_id AS id_a,
|
|
rb.chara_id AS id_b,
|
|
rc.chara_id AS id_c
|
|
FROM succession_relation_member ra
|
|
JOIN succession_relation_member rb ON ra.relation_type = rb.relation_type
|
|
JOIN succession_relation_member rc ON ra.relation_type = rc.relation_type
|
|
), affinity AS (
|
|
SELECT
|
|
trios.*,
|
|
SUM(IFNULL(relation_point, 0)) AS base_affinity
|
|
FROM trios
|
|
LEFT JOIN relation_trios rt ON trios.id_a = rt.id_a AND trios.id_b = rt.id_b AND trios.id_c = rt.id_c
|
|
LEFT JOIN succession_relation sr ON rt.relation_type = sr.relation_type
|
|
GROUP BY trios.id_a, trios.id_b, trios.id_c
|
|
|
|
UNION ALL
|
|
-- A = B = C
|
|
SELECT
|
|
n.id AS id_a,
|
|
n.name AS name_a,
|
|
n.id AS id_b,
|
|
n.name AS name_b,
|
|
n.id AS id_c,
|
|
n.name AS name_c,
|
|
0 AS base_affinity
|
|
FROM uma_names n
|
|
|
|
UNION ALL
|
|
-- A = B
|
|
SELECT
|
|
n.id AS id_a,
|
|
n.name AS name_a,
|
|
n.id AS id_a,
|
|
n.name AS id_b,
|
|
m.id AS id_c,
|
|
m.name AS name_c,
|
|
0 AS base_affinity
|
|
FROM uma_names n JOIN uma_names m ON n.id != m.id
|
|
|
|
UNION ALL
|
|
-- A = C
|
|
SELECT
|
|
n.id AS id_a,
|
|
n.name AS name_a,
|
|
m.id AS id_a,
|
|
m.name AS id_b,
|
|
n.id AS id_c,
|
|
n.name AS name_c,
|
|
0 AS base_affinity
|
|
FROM uma_names n JOIN uma_names m ON n.id != m.id
|
|
|
|
UNION ALL
|
|
-- B = C
|
|
SELECT
|
|
m.id AS id_a,
|
|
m.name AS name_a,
|
|
n.id AS id_a,
|
|
n.name AS id_b,
|
|
n.id AS id_c,
|
|
n.name AS name_c,
|
|
0 AS base_affinity
|
|
FROM uma_names n JOIN uma_names m ON n.id != m.id
|
|
)
|
|
SELECT * FROM affinity
|
|
ORDER BY id_a, id_b, id_c
|