Skip to content

Commit

Permalink
[Fixes #86086908] constrain matching on distribution to CITES taxa only
Browse files Browse the repository at this point in the history
  • Loading branch information
agnessa committed Jan 14, 2015
1 parent 5e14576 commit 2d7f46d
Show file tree
Hide file tree
Showing 3 changed files with 263 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
class FixApiQuotasAndSuspensionsViews < ActiveRecord::Migration
def change
execute "DROP VIEW IF EXISTS api_cites_quotas_view"
execute "CREATE VIEW api_cites_quotas_view AS #{view_sql('20150114084537', 'api_cites_quotas_view')}"
execute "DROP VIEW IF EXISTS api_cites_suspensions_view"
execute "CREATE VIEW api_cites_suspensions_view AS #{view_sql('20150114084537', 'api_cites_suspensions_view')}"
end
end
141 changes: 141 additions & 0 deletions db/views/api_cites_quotas_view/20150114084537.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,141 @@
SELECT tr. *,
ROW_TO_JSON(
ROW(
geo_entities.iso_code2,
geo_entities.name_en,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_en,
ROW_TO_JSON(
ROW(
geo_entities.iso_code2,
geo_entities.name_es,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_es,
ROW_TO_JSON(
ROW(
geo_entities.iso_code2,
geo_entities.name_fr,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_fr,
CASE
WHEN unit_id IS NULL THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
units.code,
units.name_en
)::api_trade_code
)
END AS unit_en,
CASE
WHEN unit_id IS NULL THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
units.code,
units.name_es
)::api_trade_code
)
END AS unit_es,
CASE
WHEN unit_id IS NULL THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
units.code,
units.name_fr
)::api_trade_code
)
END AS unit_fr
FROM (
SELECT * FROM (
SELECT tr.*,
ROW_TO_JSON(
ROW(
taxon_concept_id,
taxon_concepts.full_name,
taxon_concepts.author_year,
taxon_concepts.data->'rank_name'
)::api_taxon_concept
) AS taxon_concept,
ARRAY[]::INT[] AS matching_taxon_concept_ids
FROM (
SELECT
tr.id,
tr.type,
tr.taxon_concept_id,
tr.notes,
tr.url,
tr.start_date,
tr.publication_date::DATE,
tr.is_current,
tr.geo_entity_id,
tr.unit_id,
CASE WHEN tr.quota = -1 THEN NULL ELSE tr.quota END AS quota,
tr.public_display,
tr.nomenclature_note_en,
tr.nomenclature_note_fr,
tr.nomenclature_note_es
FROM trade_restrictions tr
WHERE tr.type IN ('Quota')
) tr
JOIN taxon_concepts ON taxon_concepts.id = tr.taxon_concept_id
WHERE taxon_concept_id IS NOT NULL
) cites_quotas_with_taxon_concept

UNION ALL

SELECT * FROM (
SELECT tr.*,
NULL::JSON AS taxon_concept,
ARRAY_AGG_NOTNULL(
distributions.taxon_concept_id
) AS matching_taxon_concept_ids
FROM (
SELECT
tr.id,
tr.type,
tr.taxon_concept_id,
tr.notes,
tr.url,
tr.start_date,
tr.publication_date::DATE,
tr.is_current,
tr.geo_entity_id,
tr.unit_id,
CASE WHEN tr.quota = -1 THEN NULL ELSE tr.quota END AS quota,
tr.public_display,
tr.nomenclature_note_en,
tr.nomenclature_note_fr,
tr.nomenclature_note_es
FROM trade_restrictions tr
WHERE tr.type IN ('Quota')
) tr
JOIN distributions ON distributions.geo_entity_id = tr.geo_entity_id
JOIN taxon_concepts ON distributions.taxon_concept_id = taxon_concepts.id
JOIN taxonomies ON taxonomies.id = taxon_concepts.taxonomy_id AND taxonomies.name = 'CITES_EU'
WHERE tr.taxon_concept_id IS NULL
GROUP BY
tr.id,
tr.type,
tr.taxon_concept_id,
tr.notes,
tr.url,
tr.start_date,
tr.publication_date,
tr.is_current,
tr.geo_entity_id,
tr.unit_id,
tr.quota,
tr.public_display,
tr.nomenclature_note_en,
tr.nomenclature_note_fr,
tr.nomenclature_note_es
) cites_quotas_without_taxon_concept
) tr
JOIN geo_entities ON geo_entities.id = tr.geo_entity_id
JOIN geo_entity_types ON geo_entities.geo_entity_type_id = geo_entity_types.id
LEFT JOIN trade_codes units ON units.id = tr.unit_id AND units.type = 'Unit';
114 changes: 114 additions & 0 deletions db/views/api_cites_suspensions_view/20150114084537.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,114 @@
SELECT
tr.*,
ROW_TO_JSON(
ROW(
geo_entities.iso_code2,
geo_entities.name_en,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_en,
ROW_TO_JSON(
ROW(
geo_entities.iso_code2,
geo_entities.name_es,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_es,
ROW_TO_JSON(
ROW(
geo_entities.iso_code2,
geo_entities.name_fr,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_fr,
ROW_TO_JSON(
ROW(
events.name,
events.effective_at::DATE,
events.url
)::api_event
) AS start_notification
FROM (
SELECT * FROM (
SELECT tr.*,
ROW_TO_JSON(
ROW(
taxon_concept_id,
taxon_concepts.full_name,
taxon_concepts.author_year,
taxon_concepts.data->'rank_name'
)::api_taxon_concept
) AS taxon_concept,
ARRAY[]::INT[] AS matching_taxon_concept_ids
FROM (
SELECT
tr.id,
tr.type,
tr.taxon_concept_id,
tr.notes,
tr.start_date::DATE,
tr.end_date::DATE,
tr.is_current,
tr.geo_entity_id,
tr.start_notification_id,
tr.end_notification_id,
tr.nomenclature_note_en,
tr.nomenclature_note_fr,
tr.nomenclature_note_es
FROM trade_restrictions tr
WHERE tr.type IN ('CitesSuspension')
) tr
JOIN taxon_concepts ON taxon_concepts.id = tr.taxon_concept_id
WHERE taxon_concept_id IS NOT NULL
) cites_suspensions_with_taxon_concept

UNION ALL

SELECT * FROM (
SELECT tr.*,
NULL::JSON AS taxon_concept,
ARRAY_AGG_NOTNULL(
distributions.taxon_concept_id
) AS matching_taxon_concept_ids
FROM (
SELECT
tr.id,
tr.type,
tr.taxon_concept_id,
tr.notes,
tr.start_date::DATE,
tr.end_date::DATE,
tr.is_current,
tr.geo_entity_id,
tr.start_notification_id,
tr.end_notification_id,
tr.nomenclature_note_en,
tr.nomenclature_note_fr,
tr.nomenclature_note_es
FROM trade_restrictions tr
WHERE tr.type IN ('CitesSuspension')
) tr
JOIN distributions ON distributions.geo_entity_id = tr.geo_entity_id
JOIN taxon_concepts ON distributions.taxon_concept_id = taxon_concepts.id
JOIN taxonomies ON taxonomies.id = taxon_concepts.taxonomy_id AND taxonomies.name = 'CITES_EU'
WHERE tr.taxon_concept_id IS NULL
GROUP BY
tr.id,
tr.type,
tr.taxon_concept_id,
tr.notes,
tr.start_date,
tr.end_date,
tr.is_current,
tr.geo_entity_id,
tr.start_notification_id,
tr.end_notification_id,
tr.nomenclature_note_en,
tr.nomenclature_note_fr,
tr.nomenclature_note_es
) cites_suspensions_without_taxon_concept
) tr
JOIN geo_entities ON geo_entities.id = tr.geo_entity_id
JOIN geo_entity_types ON geo_entities.geo_entity_type_id = geo_entity_types.id
JOIN events ON events.id = tr.start_notification_id
AND events.type IN ('CitesSuspensionNotification');

0 comments on commit 2d7f46d

Please sign in to comment.