-
-
Notifications
You must be signed in to change notification settings - Fork 10
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
migrated partially to the exploded schema added a migration to explode the schema Necessary to migrate to a parquet based initialisation
- Loading branch information
1 parent
186e1bb
commit 5ff4e00
Showing
8 changed files
with
180 additions
and
112 deletions.
There are no files selected for viewing
34 changes: 8 additions & 26 deletions
34
...99f6f367e997fd3a7da6c1c48a288202e82d.json → ...2ebc44b6c9061b717e78a97c0a9549b5a84f.json
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
34 changes: 8 additions & 26 deletions
34
...34413c43f978f3608a08883919e3d3a983bf.json → ...15374ee3368f45250987475cce81910eec57.json
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
20 changes: 20 additions & 0 deletions
20
server/migrations/20240815200325_exploded-room-data-model.down.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,20 @@ | ||
-- Add down migration script here | ||
|
||
alter table de drop column coordinate_source; | ||
alter table en drop column coordinate_source; | ||
alter table de drop column rank_type; | ||
alter table en drop column rank_type; | ||
alter table de drop column rank_combined; | ||
alter table en drop column rank_combined; | ||
alter table de drop column rank_usage; | ||
alter table en drop column rank_usage; | ||
alter table de drop column comment; | ||
alter table en drop column comment; | ||
|
||
DROP MATERIALIZED VIEW operators_de; | ||
DROP MATERIALIZED VIEW operators_en; | ||
DROP MATERIALIZED VIEW usage; | ||
DROP MATERIALIZED VIEW computed_properties; | ||
DROP MATERIALIZED VIEW urls_de; | ||
DROP MATERIALIZED VIEW urls_en; | ||
DROP MATERIALIZED VIEW sources; |
99 changes: 99 additions & 0 deletions
99
server/migrations/20240815200325_exploded-room-data-model.up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,99 @@ | ||
-- Add up migration script here | ||
|
||
alter table de | ||
add coordinate_accuracy text generated always as ((((data -> 'coords'::text) ->> 'accuracy'::text))::text) stored null; | ||
alter table en | ||
add coordinate_accuracy text generated always as ((((data -> 'coords'::text) ->> 'accuracy'::text))::text) stored null; | ||
alter table de | ||
add coordinate_source text generated always as ((((data -> 'coords'::text) ->> 'source'::text))::text) stored not null; | ||
alter table en | ||
add coordinate_source text generated always as ((((data -> 'coords'::text) ->> 'source'::text))::text) stored not null; | ||
alter table de | ||
add comment text generated always as (((data -> 'props'::text) ->> 'comment'::text)::text) stored null; | ||
alter table en | ||
add comment text generated always as (((data -> 'props'::text) ->> 'comment'::text)::text) stored null; | ||
|
||
CREATE MATERIALIZED VIEW ranking_factors AS | ||
SELECT DISTINCT | ||
data -> 'id' as id, | ||
data -> 'ranking_factors' ->> 'rank_type' as rank_type, | ||
data -> 'ranking_factors' ->> 'rank_combined' as rank_combined, | ||
data -> 'ranking_factors' ->> 'rank_usage' as rank_usage, | ||
data -> 'ranking_factors' ->> 'rank_custom' as rank_custom, | ||
data -> 'ranking_factors' ->> 'rank_boost' as rank_boost | ||
from de; | ||
|
||
CREATE MATERIALIZED VIEW operators_de AS | ||
SELECT DISTINCT data -> 'props' -> 'operator' ->> 'id' as id, | ||
data -> 'props' -> 'operator' ->> 'url' as url, | ||
data -> 'props' -> 'operator' ->> 'code' as code, | ||
data -> 'props' -> 'operator' ->> 'name' as name | ||
from de; | ||
|
||
CREATE MATERIALIZED VIEW operators_en AS | ||
SELECT DISTINCT data -> 'props' -> 'operator' ->> 'id' as id, | ||
data -> 'props' -> 'operator' ->> 'url' as url, | ||
data -> 'props' -> 'operator' ->> 'code' as code, | ||
data -> 'props' -> 'operator' ->> 'name' as name | ||
from en; | ||
|
||
CREATE MATERIALIZED VIEW usage AS | ||
SELECT DISTINCT data -> 'usage' ->> 'name' as name, | ||
data -> 'usage' ->> 'din_277' as din_277, | ||
data -> 'usage' ->> 'din_277_desc' as din_277_desc | ||
from de | ||
UNION | ||
DISTINCT | ||
SELECT DISTINCT data -> 'usage' ->> 'name' as name, | ||
data -> 'usage' ->> 'din_277' as din_277, | ||
data -> 'usage' ->> 'din_277_desc' as din_277_desc | ||
from en; | ||
|
||
CREATE MATERIALIZED VIEW computed_properties as | ||
( | ||
with facts(key, fact) as (SELECT key, JSON_ARRAY_ELEMENTS((data -> 'props' -> 'computed')::json) as fact | ||
from de), | ||
extracted_facts(key, name, value) as (Select key, fact ->> 'name' as name, fact ->> 'text' as value | ||
From facts) | ||
|
||
select distinct f.key, | ||
room_keys.value as room_key, | ||
address.value as address, | ||
level.value as level, | ||
arch_name.value as arch_name, | ||
room_cnt.value as room_cnt, | ||
building_cnt.value as building_cnt | ||
from extracted_facts f | ||
left outer join extracted_facts room_keys on f.key = room_keys.key and room_keys.name = 'Gebäudekennungen' | ||
left outer join extracted_facts address on f.key = address.key and address.name = 'Adresse' | ||
left outer join extracted_facts level on f.key = level.key and level.name = 'Stockwerk' | ||
left outer join extracted_facts arch_name on f.key = arch_name.key and arch_name.name = 'Architekten-Name' | ||
left outer join extracted_facts room_cnt on f.key = room_cnt.key and room_cnt.name = 'Anzahl Räume' | ||
left outer join extracted_facts building_cnt | ||
on f.key = building_cnt.key and building_cnt.name = 'Anzahl Gebäude' | ||
); | ||
|
||
CREATE MATERIALIZED VIEW urls_de as | ||
( | ||
with unrolled_urls(key, url) as (SELECT key, JSON_ARRAY_ELEMENTS((data -> 'props' ->> 'links')::json) as url | ||
from de) | ||
SELECT key, url ->> 'url' as url, url ->> 'text' as text | ||
FROM unrolled_urls); | ||
|
||
CREATE MATERIALIZED VIEW urls_en as | ||
( | ||
with unrolled_urls(key, url) as (SELECT key, JSON_ARRAY_ELEMENTS((data -> 'props' ->> 'links')::json) as url | ||
from en) | ||
SELECT key, url ->> 'url' as url, url ->> 'text' as text | ||
FROM unrolled_urls); | ||
|
||
CREATE MATERIALIZED VIEW sources as | ||
( | ||
with unrolled_sources(key, source) as (SELECT key, | ||
JSON_ARRAY_ELEMENTS((data -> 'sources' -> 'base')::json) as source | ||
from de) | ||
SELECT key, | ||
source ->> 'url' as url, | ||
source ->> 'name' as name | ||
FROM unrolled_sources | ||
ORDER BY key, source ->> 'name'); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.