Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add geo entity ids to api responses #990

Open
wants to merge 3 commits into
base: develop
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions app/serializers/species/geo_entity_serializer.rb
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
class Species::GeoEntitySerializer < ActiveModel::Serializer
attributes :id, :name, :iso_code2, :geo_entity_type

def geo_entity_type
object.geo_entity_type.name
end
Expand Down
19 changes: 17 additions & 2 deletions app/serializers/species/show_taxon_concept_serializer.rb
Original file line number Diff line number Diff line change
Expand Up @@ -122,7 +122,15 @@ def distributions_with_tags_and_references
).where(
taxon_concept_id: object.id
).select(
"name_en AS name, name_en AS country, ARRAY_TO_STRING(tags, ',') AS tags_list, ARRAY_TO_STRING(citations, '; ') AS country_references"
<<-SQL.squish
iso_code2,
geo_entity_id,
json_build_object(
'id', geo_entity_id
) AS geo_entity,
ARRAY_TO_STRING(tags, ',') AS tags_list,
ARRAY_TO_STRING(citations, '; ') AS country_references
SQL
).order(
'name_en'
).all
Expand All @@ -138,7 +146,14 @@ def distributions_with_tags_and_references_trimmed
).where(
taxon_concept_id: object.id
).select(
"iso_code2, ARRAY_TO_STRING(tags, ',') AS tags_list"
<<-SQL.squish
iso_code2,
geo_entity_id,
json_build_object(
'id', geo_entity_id
) AS geo_entity,
ARRAY_TO_STRING(tags, ',') AS tags_list
SQL
).order(
'iso_code2'
).all
Expand Down
58 changes: 58 additions & 0 deletions db/migrate/20240815120000_add_geo_entity_id_to_several_views.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
class AddGeoEntityIdToSeveralViews < ActiveRecord::Migration[4.2]
def up
safety_assured do
execute <<-SQL.squish
DROP TYPE api_geo_entity CASCADE;
CREATE TYPE api_geo_entity AS (
id INT,
iso_code2 TEXT,
name TEXT,
type TEXT
);
SQL

execute 'DROP VIEW IF EXISTS api_cites_listing_changes_view;'
execute 'DROP VIEW IF EXISTS api_eu_listing_changes_view;'
execute 'DROP VIEW IF EXISTS api_cites_quotas_view;'
execute 'DROP VIEW IF EXISTS api_cites_suspensions_view;'
execute 'DROP VIEW IF EXISTS api_eu_decisions_view;'
execute 'DROP VIEW IF EXISTS taxon_concepts_distributions_view;'


execute "CREATE VIEW api_cites_listing_changes_view AS #{view_sql('20240815120000', 'api_cites_listing_changes_view')}"
execute "CREATE VIEW api_eu_listing_changes_view AS #{view_sql('20240815120000', 'api_eu_listing_changes_view')}"
execute "CREATE VIEW api_cites_quotas_view AS #{view_sql('20240815120000', 'api_cites_quotas_view')}"
execute "CREATE VIEW api_cites_suspensions_view AS #{view_sql('20240815120000', 'api_cites_suspensions_view')}"
execute "CREATE VIEW api_eu_decisions_view AS #{view_sql('20240815120000', 'api_eu_decisions_view')}"
execute "CREATE VIEW taxon_concepts_distributions_view AS #{view_sql('20240815120000', 'taxon_concepts_distributions_view')}"
end
end

def down
safety_assured do
execute <<-SQL.squish
DROP TYPE api_geo_entity CASCADE;
CREATE TYPE api_geo_entity AS (
iso_code2 TEXT,
name TEXT,
type TEXT
);
SQL

execute 'DROP VIEW IF EXISTS api_cites_listing_changes_view;'
execute 'DROP VIEW IF EXISTS api_eu_listing_changes_view;'
execute 'DROP VIEW IF EXISTS api_cites_quotas_view;'
execute 'DROP VIEW IF EXISTS api_cites_suspensions_view;'
execute 'DROP VIEW IF EXISTS api_eu_decisions_view;'
execute 'DROP VIEW IF EXISTS taxon_concepts_distributions_view;'


execute "CREATE VIEW api_cites_listing_changes_view AS #{view_sql('20230509172742', 'api_cites_listing_changes_view')}"
execute "CREATE VIEW api_eu_listing_changes_view AS #{view_sql('20141230193844', 'api_eu_listing_changes_view')}"
execute "CREATE VIEW api_cites_quotas_view AS #{view_sql('20221014151355', 'api_cites_quotas_view')}"
execute "CREATE VIEW api_cites_suspensions_view AS #{view_sql('20240724113700', 'api_cites_suspensions_view')}"
execute "CREATE VIEW api_eu_decisions_view AS #{view_sql('20220808165846', 'api_eu_decisions_view')}"
execute "CREATE VIEW taxon_concepts_distributions_view AS #{view_sql('20141223141125', 'taxon_concepts_distributions_view')}"
end
end
end
192 changes: 192 additions & 0 deletions db/views/api_cites_listing_changes_view/20240815120000.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,192 @@
SELECT
listing_changes_mview.id,
event_id,
taxon_concept_id,
original_taxon_concept_id,
CASE
WHEN listing_changes_mview.change_type_name = 'DELETION'
OR listing_changes_mview.change_type_name = 'RESERVATION_WITHDRAWAL'
THEN FALSE
ELSE listing_changes_mview.is_current
END AS is_current,
listing_changes_mview.effective_at::DATE,
listing_changes_mview.species_listing_name,
listing_changes_mview.change_type_name,
CASE
WHEN listing_changes_mview.change_type_name = 'ADDITION' THEN '+'
WHEN listing_changes_mview.change_type_name = 'DELETION' THEN '-'
WHEN listing_changes_mview.change_type_name = 'RESERVATION' THEN 'R+'
WHEN listing_changes_mview.change_type_name = 'RESERVATION_WITHDRAWAL' THEN 'R-'
ELSE ''
END AS change_type,
listing_changes_mview.inclusion_taxon_concept_id,
listing_changes_mview.listed_geo_entities_ids,
listing_changes_mview.excluded_geo_entities_ids,
listing_changes_mview.party_id,
CASE
WHEN party_id IS NULL THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
party_id,
party_iso_code,
party_full_name_en,
geo_entity_type
)::api_geo_entity
)
END AS party_en,
CASE
WHEN party_id IS NULL THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
party_id,
party_iso_code,
party_full_name_es,
geo_entity_type
)::api_geo_entity
)
END AS party_es,
CASE
WHEN party_id IS NULL THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
party_id,
party_iso_code,
party_full_name_fr,
geo_entity_type
)::api_geo_entity
)
END AS party_fr,
CASE
WHEN listing_changes_mview.auto_note_en IS NULL
AND listing_changes_mview.inherited_full_note_en IS NULL
AND listing_changes_mview.inherited_short_note_en IS NULL
AND listing_changes_mview.full_note_en IS NULL
AND listing_changes_mview.short_note_en IS NULL
AND listing_changes_mview.nomenclature_note_en IS NULL
THEN NULL
ELSE
CASE
WHEN LENGTH(listing_changes_mview.auto_note_en) > 0 THEN '[' || listing_changes_mview.auto_note_en || '] '
ELSE ''
END
|| CASE
WHEN LENGTH(listing_changes_mview.inherited_full_note_en) > 0 THEN strip_tags(listing_changes_mview.inherited_full_note_en)
WHEN LENGTH(listing_changes_mview.inherited_short_note_en) > 0 THEN strip_tags(listing_changes_mview.inherited_short_note_en)
WHEN LENGTH(listing_changes_mview.full_note_en) > 0 THEN strip_tags(listing_changes_mview.full_note_en)
WHEN LENGTH(listing_changes_mview.short_note_en) > 0 THEN strip_tags(listing_changes_mview.short_note_en)
ELSE ''
END
|| CASE
WHEN LENGTH(listing_changes_mview.nomenclature_note_en) > 0 THEN strip_tags(listing_changes_mview.nomenclature_note_en)
ELSE ''
END
END AS annotation_en,
CASE
WHEN listing_changes_mview.auto_note_es IS NULL
AND listing_changes_mview.inherited_full_note_es IS NULL
AND listing_changes_mview.inherited_short_note_es IS NULL
AND listing_changes_mview.full_note_es IS NULL
AND listing_changes_mview.short_note_es IS NULL
AND listing_changes_mview.nomenclature_note_es IS NULL
THEN NULL
ELSE
CASE
WHEN LENGTH(listing_changes_mview.auto_note_es) > 0 THEN '[' || listing_changes_mview.auto_note_es || '] '
ELSE ''
END
|| CASE
WHEN LENGTH(listing_changes_mview.inherited_full_note_es) > 0 THEN strip_tags(listing_changes_mview.inherited_full_note_es)
WHEN LENGTH(listing_changes_mview.inherited_short_note_es) > 0 THEN strip_tags(listing_changes_mview.inherited_short_note_es)
WHEN LENGTH(listing_changes_mview.full_note_es) > 0 THEN strip_tags(listing_changes_mview.full_note_es)
WHEN LENGTH(listing_changes_mview.short_note_es) > 0 THEN strip_tags(listing_changes_mview.short_note_es)
ELSE ''
END
|| CASE
WHEN LENGTH(listing_changes_mview.nomenclature_note_en) > 0 THEN strip_tags(listing_changes_mview.nomenclature_note_en)
ELSE ''
END
END AS annotation_es,
CASE
WHEN listing_changes_mview.auto_note_fr IS NULL
AND listing_changes_mview.inherited_full_note_fr IS NULL
AND listing_changes_mview.inherited_short_note_fr IS NULL
AND listing_changes_mview.full_note_fr IS NULL
AND listing_changes_mview.short_note_fr IS NULL
AND listing_changes_mview.nomenclature_note_fr IS NULL
THEN NULL
ELSE
CASE
WHEN LENGTH(listing_changes_mview.auto_note_fr) > 0 THEN '[' || listing_changes_mview.auto_note_fr || '] '
ELSE ''
END
|| CASE
WHEN LENGTH(listing_changes_mview.inherited_full_note_fr) > 0 THEN strip_tags(listing_changes_mview.inherited_full_note_fr)
WHEN LENGTH(listing_changes_mview.inherited_short_note_fr) > 0 THEN strip_tags(listing_changes_mview.inherited_short_note_fr)
WHEN LENGTH(listing_changes_mview.full_note_fr) > 0 THEN strip_tags(listing_changes_mview.full_note_fr)
WHEN LENGTH(listing_changes_mview.short_note_fr) > 0 THEN strip_tags(listing_changes_mview.short_note_fr)
ELSE ''
END
|| CASE
WHEN LENGTH(listing_changes_mview.nomenclature_note_fr) > 0 THEN strip_tags(listing_changes_mview.nomenclature_note_fr)
ELSE ''
END
END AS annotation_fr,
CASE
WHEN listing_changes_mview.hash_ann_symbol IS NULL
AND listing_changes_mview.hash_full_note_en IS NULL
THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
listing_changes_mview.hash_ann_symbol,
strip_tags(listing_changes_mview.hash_full_note_en)
)::api_annotation
)
END AS hash_annotation_en,
CASE
WHEN listing_changes_mview.hash_ann_symbol IS NULL
AND listing_changes_mview.hash_full_note_es IS NULL
THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
listing_changes_mview.hash_ann_parent_symbol || ' ' || listing_changes_mview.hash_ann_symbol,
strip_tags(listing_changes_mview.hash_full_note_es)
)::api_annotation
)
END AS hash_annotation_es,
CASE
WHEN listing_changes_mview.hash_ann_symbol IS NULL
AND listing_changes_mview.hash_full_note_fr IS NULL
THEN NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
listing_changes_mview.hash_ann_symbol,
strip_tags(listing_changes_mview.hash_full_note_fr)
)::api_annotation
)
END AS hash_annotation_fr,
listing_changes_mview.show_in_history,
listing_changes_mview.full_note_en,
listing_changes_mview.short_note_en,
listing_changes_mview.auto_note_en,
listing_changes_mview.hash_full_note_en,
listing_changes_mview.hash_ann_parent_symbol,
listing_changes_mview.hash_ann_symbol,
listing_changes_mview.inherited_full_note_en,
listing_changes_mview.inherited_short_note_en,
listing_changes_mview.nomenclature_note_en,
listing_changes_mview.nomenclature_note_fr,
listing_changes_mview.nomenclature_note_es,
CASE
WHEN change_type_name = 'ADDITION' THEN 0
WHEN change_type_name = 'RESERVATION' THEN 1
WHEN change_type_name = 'RESERVATION_WITHDRAWAL' THEN 2
WHEN change_type_name = 'DELETION' THEN 3
END AS change_type_order
FROM cites_listing_changes_mview listing_changes_mview
WHERE "listing_changes_mview"."show_in_history";
104 changes: 104 additions & 0 deletions db/views/api_cites_quotas_view/20240815120000.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,104 @@
SELECT tr. *,
ROW_TO_JSON(
ROW(
geo_entity_types.id,
geo_entities.iso_code2,
geo_entities.name_en,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_en,
ROW_TO_JSON(
ROW(
geo_entity_types.id,
geo_entities.iso_code2,
geo_entities.name_es,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_es,
ROW_TO_JSON(
ROW(
geo_entity_types.id,
geo_entities.iso_code2,
geo_entities.name_fr,
geo_entity_types.name
)::api_geo_entity
) AS geo_entity_fr,
COALESCE(trade_restriction_sources.source_ids, '[]') AS source_ids,
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.*,
CASE
WHEN tr.taxon_concept_id IS NULL
THEN
NULL::JSON
ELSE
ROW_TO_JSON(
ROW(
taxon_concept_id,
taxon_concepts.full_name,
taxon_concepts.author_year,
taxon_concepts.data->'rank_name'
)::api_taxon_concept
)
END AS taxon_concept
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
LEFT JOIN taxon_concepts ON taxon_concepts.id = tr.taxon_concept_id
) cites_quotas_with_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'
LEFT JOIN LATERAL (
SELECT JSON_AGG(trade_restriction_sources.source_id) AS source_ids
FROM trade_restriction_sources
WHERE tr.id = trade_restriction_sources.trade_restriction_id
) trade_restriction_sources ON true;
Loading