diff --git a/app/serializers/species/geo_entity_serializer.rb b/app/serializers/species/geo_entity_serializer.rb index 0996f20b58..bc6b26c64e 100644 --- a/app/serializers/species/geo_entity_serializer.rb +++ b/app/serializers/species/geo_entity_serializer.rb @@ -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 diff --git a/app/serializers/species/show_taxon_concept_serializer.rb b/app/serializers/species/show_taxon_concept_serializer.rb index 83daf20a6a..271c25671a 100644 --- a/app/serializers/species/show_taxon_concept_serializer.rb +++ b/app/serializers/species/show_taxon_concept_serializer.rb @@ -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 @@ -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 diff --git a/db/migrate/20240815120000_add_geo_entity_id_to_several_views.rb b/db/migrate/20240815120000_add_geo_entity_id_to_several_views.rb new file mode 100644 index 0000000000..c11be8139d --- /dev/null +++ b/db/migrate/20240815120000_add_geo_entity_id_to_several_views.rb @@ -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 diff --git a/db/views/api_cites_listing_changes_view/20240815120000.sql b/db/views/api_cites_listing_changes_view/20240815120000.sql new file mode 100644 index 0000000000..433eb50759 --- /dev/null +++ b/db/views/api_cites_listing_changes_view/20240815120000.sql @@ -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"; diff --git a/db/views/api_cites_quotas_view/20240815120000.sql b/db/views/api_cites_quotas_view/20240815120000.sql new file mode 100644 index 0000000000..d5851b331f --- /dev/null +++ b/db/views/api_cites_quotas_view/20240815120000.sql @@ -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; diff --git a/db/views/api_cites_suspensions_view/20240815120000.sql b/db/views/api_cites_suspensions_view/20240815120000.sql new file mode 100644 index 0000000000..e279e6c3db --- /dev/null +++ b/db/views/api_cites_suspensions_view/20240815120000.sql @@ -0,0 +1,90 @@ +SELECT + tr.*, + ROW_TO_JSON( + ROW( + geo_entities.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_entities.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_entities.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, + ROW_TO_JSON( + ROW( + start_event.name, + start_event.effective_at::DATE, + start_event.url + )::api_event + ) AS start_notification, + ROW_TO_JSON( + ROW( + end_event.name, + end_event.effective_at::DATE, + end_event.url + )::api_event + ) AS end_notification +FROM ( + SELECT * FROM ( + SELECT tr.*, + CASE + WHEN tr.taxon_concept_id IS NOT NULL THEN + ROW_TO_JSON( + ROW( + tr.taxon_concept_id, + taxon_concepts.full_name, + taxon_concepts.author_year, + taxon_concepts.data->'rank_name' + )::api_taxon_concept + ) + ELSE + NULL::JSON + END AS taxon_concept + 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.applies_to_import, + 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 + LEFT JOIN taxon_concepts ON taxon_concepts.id = tr.taxon_concept_id + ) cites_suspensions_without_taxon_concept +) tr +LEFT JOIN geo_entities ON geo_entities.id = tr.geo_entity_id +LEFT JOIN geo_entity_types ON geo_entities.geo_entity_type_id = geo_entity_types.id +JOIN events start_event ON start_event.id = tr.start_notification_id + AND start_event.type IN ('CitesSuspensionNotification') +LEFT JOIN events end_event ON end_event.id = tr.end_notification_id + AND end_event.type IN ('CitesSuspensionNotification') +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; diff --git a/db/views/api_eu_decisions_view/20240815120000.sql b/db/views/api_eu_decisions_view/20240815120000.sql new file mode 100644 index 0000000000..755a2b3578 --- /dev/null +++ b/db/views/api_eu_decisions_view/20240815120000.sql @@ -0,0 +1,142 @@ +SELECT +eu_decisions.id, +eu_decisions.type, +eu_decisions.taxon_concept_id, +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, +eu_decisions.notes, +CASE + WHEN eu_decisions.type = 'EuOpinion' + THEN eu_decisions.start_date::DATE + WHEN eu_decisions.type = 'EuSuspension' + THEN start_event.effective_at::DATE +END AS start_date, +CASE + WHEN eu_decisions.type = 'EuOpinion' + THEN eu_decisions.is_current + WHEN eu_decisions.type = 'EuSuspension' + THEN + CASE + WHEN start_event.effective_at <= current_date AND start_event.is_current = true + AND (eu_decisions.end_event_id IS NULL OR end_event.effective_at > current_date) + THEN TRUE + ELSE + FALSE + END +END AS is_current, +eu_decisions.geo_entity_id, +ROW_TO_JSON( + ROW( + geo_entities.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_entities.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_entities.id, + geo_entities.iso_code2, + geo_entities.name_fr, + geo_entity_types.name + )::api_geo_entity +) AS geo_entity_fr, +eu_decisions.start_event_id, +ROW_TO_JSON( + ROW( + start_event.name || CASE WHEN start_event.type = 'EcSrg' THEN ' Soc' ELSE '' END, + start_event.effective_at::DATE, + start_event.url + )::api_event +) AS start_event, +start_event.private_url AS private_url, +eu_decisions.end_event_id, +ROW_TO_JSON( + ROW( + end_event.name, + end_event.effective_at::DATE, + end_event.url + )::api_event +) AS end_event, +documents.id AS intersessional_decision_id, +eu_decisions.term_id, +ROW_TO_JSON( + ROW( + terms.code, + terms.name_en + )::api_trade_code +) AS term_en, +ROW_TO_JSON( + ROW( + terms.code, + terms.name_es + )::api_trade_code +) AS term_es, +ROW_TO_JSON( + ROW( + terms.code, + terms.name_fr + )::api_trade_code +) AS term_fr, +ROW_TO_JSON( + ROW( + sources.code, + sources.name_en + )::api_trade_code +) AS source_en, +ROW_TO_JSON( + ROW( + sources.code, + sources.name_es + )::api_trade_code +) AS source_es, +ROW_TO_JSON( + ROW( + sources.code, + sources.name_fr + )::api_trade_code +) AS source_fr, +eu_decisions.source_id, +eu_decisions.eu_decision_type_id, +ROW_TO_JSON( + ROW( + eu_decision_types.name, + eu_decision_types.tooltip, + eu_decision_types.decision_type + )::api_eu_decision_type +) AS eu_decision_type, +eu_decisions.srg_history_id, +ROW_TO_JSON( + ROW( + srg_histories.name, + srg_histories.tooltip + )::api_srg_history +) AS srg_history, +eu_decisions.nomenclature_note_en, +eu_decisions.nomenclature_note_fr, +eu_decisions.nomenclature_note_es +FROM eu_decisions +JOIN geo_entities ON geo_entities.id = eu_decisions.geo_entity_id +JOIN geo_entity_types ON geo_entities.geo_entity_type_id = geo_entity_types.id +JOIN taxon_concepts ON taxon_concepts.id = eu_decisions.taxon_concept_id +LEFT JOIN events AS start_event ON start_event.id = eu_decisions.start_event_id +LEFT JOIN events AS end_event ON end_event.id = eu_decisions.end_event_id +LEFT JOIN trade_codes terms ON terms.id = eu_decisions.term_id AND terms.type = 'Term' +LEFT JOIN trade_codes sources ON sources.id = eu_decisions.source_id AND sources.type = 'Source' +LEFT JOIN eu_decision_types ON eu_decision_types.id = eu_decisions.eu_decision_type_id +LEFT JOIN srg_histories ON srg_histories.id = eu_decisions.srg_history_id +LEFT JOIN documents ON documents.id = eu_decisions.document_id; diff --git a/db/views/api_eu_listing_changes_view/20240815120000.sql b/db/views/api_eu_listing_changes_view/20240815120000.sql new file mode 100644 index 0000000000..90347d3e46 --- /dev/null +++ b/db/views/api_eu_listing_changes_view/20240815120000.sql @@ -0,0 +1,196 @@ +SELECT + listing_changes_mview.id, + event_id, + ROW_TO_JSON( + ROW( + events.description, + events.effective_at, + events.url + )::api_event + ) AS eu_regulation, + taxon_concept_id, + original_taxon_concept_id, + listing_changes_mview.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.party_id, + CASE + WHEN listing_changes_mview.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 listing_changes_mview.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 listing_changes_mview.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 eu_listing_changes_mview listing_changes_mview +JOIN events ON events.id = listing_changes_mview.event_id +WHERE "listing_changes_mview"."show_in_history"; diff --git a/db/views/taxon_concepts_distributions_view/20240815120000.sql b/db/views/taxon_concepts_distributions_view/20240815120000.sql new file mode 100644 index 0000000000..d470234954 --- /dev/null +++ b/db/views/taxon_concepts_distributions_view/20240815120000.sql @@ -0,0 +1,53 @@ +SELECT + taxon_concepts.id AS id, + taxon_concepts.legacy_id AS legacy_id, + data->'phylum_name' AS phylum_name, + data->'class_name' AS class_name, + data->'order_name' AS order_name, + data->'family_name' AS family_name, + full_name, + data->'rank_name' AS rank_name, + geo_entities.id AS geo_entity_id, + geo_entity_types.name AS geo_entity_type, + geo_entities.name_en AS geo_entity_name, + geo_entities.iso_code2 AS geo_entity_iso_code2, + string_agg(tags.name, ', ') AS tags, + "references".citation AS reference_full, + "references".id AS reference_id, + "references".legacy_id AS reference_legacy_id, + taxonomies.name AS taxonomy_name, + taxonomic_position, + taxonomy_id, + ARRAY_TO_STRING( + ARRAY[ + distribution_note.note, + distributions.internal_notes + ], + E'\n' + ) AS internal_notes, + to_char(distributions.created_at, 'DD/MM/YYYY') AS created_at, + uc.name AS created_by, + to_char(distributions.updated_at, 'DD/MM/YYYY') AS updated_at, + uu.name AS updated_by +FROM distributions +RIGHT JOIN taxon_concepts ON distributions.taxon_concept_id = taxon_concepts.id +LEFT JOIN taxonomies ON taxonomies.id = taxon_concepts.taxonomy_id +LEFT JOIN geo_entities ON geo_entities.id = distributions.geo_entity_id +LEFT JOIN geo_entity_types ON geo_entity_types.id = geo_entities.geo_entity_type_id +LEFT JOIN distribution_references ON distribution_references.distribution_id = distributions.id +LEFT JOIN "references" ON "references".id = distribution_references.reference_id +LEFT JOIN taggings ON taggings.taggable_id = distributions.id + AND taggings.taggable_type = 'Distribution' +LEFT JOIN tags ON tags.id = taggings.tag_id +LEFT JOIN comments distribution_note + ON distribution_note.commentable_id = taxon_concepts.id + AND distribution_note.commentable_type = 'TaxonConcept' + AND distribution_note.comment_type = 'Distribution' +LEFT JOIN users uc ON distributions.created_by_id = uc.id +LEFT JOIN users uu ON distributions.updated_by_id = uu.id +WHERE taxon_concepts.name_status IN ('A') +GROUP BY taxon_concepts.id, taxon_concepts.legacy_id, + geo_entities.id, geo_entity_types.name, geo_entities.name_en, + geo_entities.iso_code2, "references".citation, "references".id, + taxonomies.name, distributions.internal_notes, distribution_note.note, + uc.name, uu.name, distributions.created_at, distributions.updated_at; diff --git a/spec/factories/ranks.rb b/spec/factories/ranks.rb index 788edbf61e..d4c60763e7 100644 --- a/spec/factories/ranks.rb +++ b/spec/factories/ranks.rb @@ -1,18 +1,18 @@ def attributes_for_rank(name) - # == Schema Information - # - # Table name: ranks - # - # id :integer not null, primary key - # display_name_en :text not null - # display_name_es :text - # display_name_fr :text - # fixed_order :boolean default(FALSE), not null - # name :string(255) not null - # taxonomic_position :string(255) default("0"), not null - # created_at :datetime not null - # updated_at :datetime not null - # +# == Schema Information +# +# Table name: ranks +# +# id :integer not null, primary key +# display_name_en :text not null +# display_name_es :text +# display_name_fr :text +# fixed_order :boolean default(FALSE), not null +# name :string(255) not null +# taxonomic_position :string(255) default("0"), not null +# created_at :datetime not null +# updated_at :datetime not null +# send("attributes_for_#{name.downcase}") end