lahmanlite/sql/parkaliases.sql

34 lines
795 B
PL/PgSQL

pragma foreign_keys = 0;
begin;
attach database 'lahman-raw.db' as 'raw';
create temp table if not exists "parkaliases" (
"parkID" text,
"alias" text
);
-- split aliases by semicolon
with recursive aliases(parkid, alias) as (
select "park.key", "park.alias" from "raw"."parks"
union
select parkid, trim(substr(alias, instr(alias, ";") + 1)) as a
from aliases
where a != ''
) insert into parkaliases
select parkid, case instr(alias, ";")
when 0 then alias
else trim(substr(alias, 1, instr(alias, ";") - 1)) end as a
from aliases
where a != '';
CREATE TABLE IF NOT EXISTS main."parkaliases" (
"park" TEXT,
"alias" TEXT,
PRIMARY KEY("park","alias"),
foreign key("park") references "parks"("ID")
);
insert into main."parkaliases" select distinct * from temp."parkaliases";
commit;