Skip to content

Commit

Permalink
SEARCH-359 adjunct: create a view for area containments, use in Data:…
Browse files Browse the repository at this point in the history
…:Area
  • Loading branch information
ianmcorvidae committed Apr 29, 2014
1 parent 7533a97 commit 04a436e
Show file tree
Hide file tree
Showing 7 changed files with 99 additions and 29 deletions.
29 changes: 29 additions & 0 deletions admin/sql/CreateViews.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,35 @@ CREATE OR REPLACE VIEW release_event AS
FROM release_unknown_country
) as q;

-- First, construct a table (recursively) of parent -> descendant connections
-- for areas, including an array of the path (the 'descendants' array).

-- Then, find the shortest path to each type of parent by joining to area,
-- distinct on descendant, type, and order by the length of the array of descendants.

-- link type de7cc874-8b1b-3a05-8272-f3834c968fb7 is the area-area 'parent of' relation
CREATE OR REPLACE VIEW area_containment AS
WITH RECURSIVE area_descendants AS (
SELECT entity0 AS parent, entity1 AS descendant, ARRAY[entity1] AS descendants
FROM l_area_area laa
JOIN link ON laa.link = link.id
JOIN link_type ON link.link_type = link_type.id
WHERE link_type.gid = 'de7cc874-8b1b-3a05-8272-f3834c968fb7'
UNION ALL
SELECT entity0 AS parent, descendant, descendants || entity1
FROM l_area_area laa
JOIN link ON laa.link=link.id
JOIN link_type ON link.link_type = link_type.id
JOIN area_descendants ON area_descendants.parent = laa.entity1
WHERE link_type.gid = 'de7cc874-8b1b-3a05-8272-f3834c968fb7'
AND NOT entity0 = ANY(descendants))
SELECT DISTINCT ON (descendant, type) descendant, area_descendants.parent, area.type, area_type.name AS type_name, descendants || area_descendants.parent AS descendant_hierarchy
FROM area_descendants
JOIN area ON area_descendants.parent = area.id
JOIN area_type ON area.type = area_type.id
WHERE area.type IN (1, 2, 3)
ORDER BY descendant, type, array_length(descendants, 1) ASC;

CREATE OR REPLACE VIEW recording_series AS
SELECT entity0 AS recording, entity1 AS series, link_order, text_value
FROM l_recording_series lrs
Expand Down
1 change: 0 additions & 1 deletion admin/sql/DropReplicationTriggers.sql
Original file line number Diff line number Diff line change
Expand Up @@ -143,7 +143,6 @@ DROP TRIGGER reptg_release_label ON release_label;
DROP TRIGGER reptg_release_packaging ON release_packaging;
DROP TRIGGER reptg_release_status ON release_status;
DROP TRIGGER reptg_release_tag ON release_tag;
DROP TRIGGER reptg_release_tag ON release_tag;
DROP TRIGGER reptg_release_group ON release_group;
DROP TRIGGER reptg_release_group_annotation ON release_group_annotation;
DROP TRIGGER reptg_release_group_gid_redirect ON release_group_gid_redirect;
Expand Down
1 change: 1 addition & 0 deletions admin/sql/DropViews.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
-- Automatically generated, do not edit.
\unset ON_ERROR_STOP

DROP VIEW area_containment;
DROP VIEW recording_series;
DROP VIEW release_event;
DROP VIEW release_group_series;
Expand Down
32 changes: 32 additions & 0 deletions admin/sql/updates/20140429-area-view.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
\set ON_ERROR_STOP 1

BEGIN;

-- First, construct a table (recursively) of parent -> descendant connections
-- for areas, including an array of the path (the 'descendants' array).

-- Then, find the shortest path to each type of parent by joining to area,
-- distinct on descendant, type, and order by the length of the array of descendants.
CREATE OR REPLACE VIEW area_containment AS
WITH RECURSIVE area_descendants AS (
SELECT entity0 AS parent, entity1 AS descendant, ARRAY[entity1] AS descendants
FROM l_area_area laa
JOIN link ON laa.link = link.id
JOIN link_type ON link.link_type = link_type.id
WHERE link_type.gid = 'de7cc874-8b1b-3a05-8272-f3834c968fb7'
UNION ALL
SELECT entity0 AS parent, descendant, descendants || entity1
FROM l_area_area laa
JOIN link ON laa.link=link.id
JOIN link_type ON link.link_type = link_type.id
JOIN area_descendants ON area_descendants.parent = laa.entity1
WHERE link_type.gid = 'de7cc874-8b1b-3a05-8272-f3834c968fb7'
AND NOT entity0 = ANY(descendants))
SELECT DISTINCT ON (descendant, type) descendant, area_descendants.parent, area.type, area_type.name AS type_name, descendants || area_descendants.parent AS descendant_hierarchy
FROM area_descendants
JOIN area ON area_descendants.parent = area.id
JOIN area_type ON area.type = area_type.id
WHERE area.type IN (1, 2, 3)
ORDER BY descendant, type, array_length(descendants, 1) ASC;

COMMIT;
32 changes: 32 additions & 0 deletions admin/sql/updates/schema-change/20.slave.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@
-- 20140215-add-instruments-documentation.sql
-- 20140318-series.sql
-- 20140418-series-instrument-functions.sql
-- 20140429-area-view.sql
\set ON_ERROR_STOP 1
BEGIN;
--------------------------------------------------------------------------------
Expand Down Expand Up @@ -1682,4 +1683,35 @@ AS $$
END;
$$ LANGUAGE 'plpgsql';

--------------------------------------------------------------------------------
SELECT '20140429-area-view.sql';


-- First, construct a table (recursively) of parent -> descendant connections
-- for areas, including an array of the path (the 'descendants' array).

-- Then, find the shortest path to each type of parent by joining to area,
-- distinct on descendant, type, and order by the length of the array of descendants.
CREATE OR REPLACE VIEW area_containment AS
WITH RECURSIVE area_descendants AS (
SELECT entity0 AS parent, entity1 AS descendant, ARRAY[entity1] AS descendants
FROM l_area_area laa
JOIN link ON laa.link = link.id
JOIN link_type ON link.link_type = link_type.id
WHERE link_type.gid = 'de7cc874-8b1b-3a05-8272-f3834c968fb7'
UNION ALL
SELECT entity0 AS parent, descendant, descendants || entity1
FROM l_area_area laa
JOIN link ON laa.link=link.id
JOIN link_type ON link.link_type = link_type.id
JOIN area_descendants ON area_descendants.parent = laa.entity1
WHERE link_type.gid = 'de7cc874-8b1b-3a05-8272-f3834c968fb7'
AND NOT entity0 = ANY(descendants))
SELECT DISTINCT ON (descendant, type) descendant, area_descendants.parent, area.type, area_type.name AS type_name, descendants || area_descendants.parent AS descendant_hierarchy
FROM area_descendants
JOIN area ON area_descendants.parent = area.id
JOIN area_type ON area.type = area_type.id
WHERE area.type IN (1, 2, 3)
ORDER BY descendant, type, array_length(descendants, 1) ASC;

COMMIT;
31 changes: 4 additions & 27 deletions lib/MusicBrainz/Server/Data/Area.pm
Original file line number Diff line number Diff line change
Expand Up @@ -82,7 +82,6 @@ sub load
sub load_containment
{
my ($self, @areas) = @_;
my $area_area_parent_type = 356;
# Define a map of area_type IDs to what property they correspond to
# on an Entity::Area.
my %type_parent_attribute = (
Expand All @@ -107,32 +106,10 @@ sub load_containment
my %obj_id_map = object_to_ids(@objects_to_use);
my @all_ids = keys %obj_id_map;

# First, construct a table (recursively) of parent -> descendant connections
# for areas, including an array of the path (the 'descendants' array).
#
# Then, find the shortest path to each type of parent by joining to area,
# distinct on descendant, type, and order by the length of the array of descendants.
my $query = "
WITH RECURSIVE area_descendants AS (
SELECT entity0 AS parent, entity1 AS descendant, ARRAY[entity1] AS descendants
FROM l_area_area laa
JOIN link ON laa.link = link.id
WHERE link_type = $area_area_parent_type
UNION ALL
SELECT entity0 AS parent, descendant, descendants || entity1
FROM l_area_area laa
JOIN link ON laa.link=link.id
JOIN area_descendants ON area_descendants.parent = laa.entity1
WHERE link_type = $area_area_parent_type
AND NOT entity0 = ANY(descendants))
SELECT DISTINCT ON (descendant, type) descendant, parent, area.type, descendants || parent AS descendant_hierarchy
FROM area_descendants
JOIN area ON area_descendants.parent = area.id
WHERE descendant IN (" . placeholders(@all_ids) . ")
AND area.type IN (" . placeholders(keys %type_parent_attribute) . ")
ORDER BY descendant, type, array_length(descendants, 1) ASC";

my $containment = $self->sql->select_list_of_hashes($query, @all_ids, keys %type_parent_attribute);
# See admin/sql/CreateViews.sql for a description of the area_containment view.
# If more types are added to %type_parent_attribute the view should be updated.
my $query = "SELECT descendant, parent, type FROM area_containment WHERE descendant = any(?)";
my $containment = $self->sql->select_list_of_hashes($query, \@all_ids);

my @parent_ids = grep { defined } map { $_->{parent} } @$containment;

Expand Down
2 changes: 1 addition & 1 deletion upgrade.json
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{
"20": {
"slave": ["20140310-dates.sql", "20140212-ordering-columns.sql", "20140208-drop-script_language.sql", "20140407-link-cardinality.sql", "20140311-remove-area-sortnames.sql", "20140313-remove-label-sortnames.sql", "20140214-add-instruments.sql", "20140215-add-instruments-documentation.sql", "20140318-series.sql", "20140418-series-instrument-functions.sql"],
"slave": ["20140310-dates.sql", "20140212-ordering-columns.sql", "20140208-drop-script_language.sql", "20140407-link-cardinality.sql", "20140311-remove-area-sortnames.sql", "20140313-remove-label-sortnames.sql", "20140214-add-instruments.sql", "20140215-add-instruments-documentation.sql", "20140318-series.sql", "20140418-series-instrument-functions.sql", "20140429-area-view.sql"],
"standalone": ["20140308-ordering-columns-fk.sql", "20140312-dates-trigger.sql", "20140217-instrument-triggers.sql", "20140318-series-fks.sql"]
}
}

0 comments on commit 04a436e

Please sign in to comment.