97 lines
2.9 KiB
SQL
97 lines
2.9 KiB
SQL
-- Main killmail facts + denormalized victim
|
|
CREATE TABLE killmails
|
|
(
|
|
killmail_id Int64,
|
|
killmail_hash String,
|
|
killmail_time DateTime,
|
|
|
|
-- Time helpers
|
|
kill_hour UInt8 MATERIALIZED toHour(killmail_time),
|
|
kill_day_of_week UInt8 MATERIALIZED toDayOfWeek(killmail_time),
|
|
kill_date Date MATERIALIZED toDate(killmail_time),
|
|
|
|
-- Solar system (denormalized)
|
|
solar_system_id Int32,
|
|
solar_system_name LowCardinality(String),
|
|
constellation_name LowCardinality(String),
|
|
region_name LowCardinality(String),
|
|
security Float32,
|
|
|
|
-- Victim (denormalized)
|
|
victim_character_id Int64,
|
|
victim_character_name String,
|
|
victim_corporation_id Int64,
|
|
victim_corporation_name LowCardinality(String),
|
|
victim_alliance_id Nullable(Int64),
|
|
victim_alliance_name LowCardinality(String),
|
|
victim_ship_type_id Int32,
|
|
victim_ship_type_name LowCardinality(String),
|
|
victim_ship_group_name LowCardinality(String),
|
|
victim_ship_category_name LowCardinality(String),
|
|
victim_damage_taken Int64,
|
|
|
|
-- Metadata
|
|
attacker_count UInt16,
|
|
http_last_modified DateTime
|
|
)
|
|
ENGINE = ReplacingMergeTree()
|
|
PARTITION BY toYYYYMM(killmail_time)
|
|
ORDER BY killmail_id;
|
|
|
|
-- Attackers (no duplicates per killmail_id + character_id combo)
|
|
CREATE TABLE killmail_attackers
|
|
(
|
|
killmail_id Int64,
|
|
|
|
-- Attacker (denormalized)
|
|
character_id Int64,
|
|
character_name String,
|
|
corporation_id Int64,
|
|
corporation_name LowCardinality(String),
|
|
alliance_id Nullable(Int64),
|
|
alliance_name LowCardinality(String),
|
|
ship_type_id Int32,
|
|
ship_type_name LowCardinality(String),
|
|
ship_group_name LowCardinality(String),
|
|
weapon_type_id Int32,
|
|
weapon_type_name LowCardinality(String),
|
|
|
|
damage_done Int64,
|
|
final_blow Bool,
|
|
security_status Float32
|
|
)
|
|
ENGINE = ReplacingMergeTree()
|
|
ORDER BY (killmail_id, character_id);
|
|
|
|
-- Items (no duplicates per killmail_id + flag + item_type_id combo)
|
|
CREATE TABLE killmail_items
|
|
(
|
|
killmail_id Int64,
|
|
|
|
-- Item (denormalized)
|
|
item_type_id Int32,
|
|
item_type_name String,
|
|
item_group_name LowCardinality(String),
|
|
item_category_name LowCardinality(String),
|
|
item_market_group_name LowCardinality(String),
|
|
|
|
flag Int32,
|
|
slot_type LowCardinality(String) MATERIALIZED CASE
|
|
WHEN flag BETWEEN 27 AND 34 THEN 'high'
|
|
WHEN flag BETWEEN 19 AND 26 THEN 'mid'
|
|
WHEN flag BETWEEN 11 AND 18 THEN 'low'
|
|
WHEN flag BETWEEN 92 AND 99 THEN 'rig'
|
|
WHEN flag BETWEEN 125 AND 132 THEN 'subsystem'
|
|
WHEN flag = 88 THEN 'booster'
|
|
WHEN flag = 89 THEN 'implant'
|
|
WHEN flag = 87 THEN 'drone_bay'
|
|
WHEN flag = 5 THEN 'cargo'
|
|
ELSE 'other'
|
|
END,
|
|
|
|
quantity_destroyed Int64,
|
|
quantity_dropped Int64,
|
|
singleton Int32
|
|
)
|
|
ENGINE = ReplacingMergeTree()
|
|
ORDER BY (killmail_id, flag, item_type_id); |