From 8b561b17c058d9b832ab52d63f8cff6bdbd0f592 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 16 Oct 2023 00:24:34 +0200 Subject: [PATCH 1/7] Add migrations for {designed,released}_by for cards, cycles, sets. --- db/migrate/20231015222243_add_designed_by_to_cards.rb | 5 +++++ .../20231015222301_add_released_by_to_cycles_and_sets.rb | 6 ++++++ db/schema.rb | 5 ++++- 3 files changed, 15 insertions(+), 1 deletion(-) create mode 100644 db/migrate/20231015222243_add_designed_by_to_cards.rb create mode 100644 db/migrate/20231015222301_add_released_by_to_cycles_and_sets.rb diff --git a/db/migrate/20231015222243_add_designed_by_to_cards.rb b/db/migrate/20231015222243_add_designed_by_to_cards.rb new file mode 100644 index 00000000..8ef98a10 --- /dev/null +++ b/db/migrate/20231015222243_add_designed_by_to_cards.rb @@ -0,0 +1,5 @@ +class AddDesignedByToCards < ActiveRecord::Migration[7.0] + def change + add_column :cards, :designed_by, :string + end +end diff --git a/db/migrate/20231015222301_add_released_by_to_cycles_and_sets.rb b/db/migrate/20231015222301_add_released_by_to_cycles_and_sets.rb new file mode 100644 index 00000000..f2e7b032 --- /dev/null +++ b/db/migrate/20231015222301_add_released_by_to_cycles_and_sets.rb @@ -0,0 +1,6 @@ +class AddReleasedByToCyclesAndSets < ActiveRecord::Migration[7.0] + def change + add_column :card_cycles, :released_by, :string + add_column :card_sets, :released_by, :string + end +end diff --git a/db/schema.rb b/db/schema.rb index e113afc5..d6e91a99 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -10,7 +10,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema[7.0].define(version: 2023_09_23_064748) do +ActiveRecord::Schema[7.0].define(version: 2023_10_15_222301) do # These are extensions that must be enabled in order to support this database enable_extension "pgcrypto" enable_extension "plpgsql" @@ -22,6 +22,7 @@ t.datetime "updated_at", null: false t.date "date_release" t.string "legacy_code" + t.string "released_by" end create_table "card_pools", id: :string, force: :cascade do |t| @@ -66,6 +67,7 @@ t.datetime "created_at", null: false t.datetime "updated_at", null: false t.string "legacy_code" + t.string "released_by" end create_table "card_subtypes", id: :string, force: :cascade do |t| @@ -117,6 +119,7 @@ t.boolean "rez_effect", default: false t.boolean "trash_ability", default: false t.string "attribution" + t.string "designed_by" t.index ["card_type_id"], name: "index_cards_on_card_type_id" t.index ["faction_id"], name: "index_cards_on_faction_id" t.index ["side_id"], name: "index_cards_on_side_id" From 2ddaaaf456d49b1476cfd9444633159861736c6f Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 16 Oct 2023 00:31:33 +0200 Subject: [PATCH 2/7] Populate {design,releas}ed_by on cards, cycles, and sets. --- lib/tasks/cards.rake | 7 +++++-- 1 file changed, 5 insertions(+), 2 deletions(-) diff --git a/lib/tasks/cards.rake b/lib/tasks/cards.rake index 0967251d..d1248c52 100644 --- a/lib/tasks/cards.rake +++ b/lib/tasks/cards.rake @@ -107,6 +107,7 @@ namespace :cards do is_unique: card["is_unique"], display_subtypes: flatten_subtypes(subtypes, card["subtypes"]), attribution: card["attribution"], + designed_by: card["designed_by"], ) if card.key?("cost") new_card.cost = (card["cost"].nil? ? -1 : card["cost"]) @@ -252,7 +253,8 @@ namespace :cards do { id: c['id'], name: c['name'], - legacy_code: c['legacy_code'] + legacy_code: c['legacy_code'], + released_by: c['released_by'], } end CardCycle.import cycles, on_duplicate_key_update: { conflict_target: [ :id ], columns: :all } @@ -290,7 +292,8 @@ namespace :cards do "card_cycle_id": s["card_cycle_id"], "card_set_type_id": s["card_set_type_id"], "position": s["position"], - "legacy_code": s["legacy_code"] + "legacy_code": s["legacy_code"], + "released_by": s["released_by"], } end CardSet.import printings, on_duplicate_key_update: { conflict_target: [ :id ], columns: :all } From 5209e3aa43361a8c5329eac3990b30efe417390e Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 16 Oct 2023 23:05:30 +0200 Subject: [PATCH 3/7] Add released_by to printings (migration & importer). --- db/migrate/20231016210204_add_released_by_to_printings.rb | 5 +++++ db/schema.rb | 3 ++- lib/tasks/cards.rake | 1 + 3 files changed, 8 insertions(+), 1 deletion(-) create mode 100644 db/migrate/20231016210204_add_released_by_to_printings.rb diff --git a/db/migrate/20231016210204_add_released_by_to_printings.rb b/db/migrate/20231016210204_add_released_by_to_printings.rb new file mode 100644 index 00000000..40cbbac1 --- /dev/null +++ b/db/migrate/20231016210204_add_released_by_to_printings.rb @@ -0,0 +1,5 @@ +class AddReleasedByToPrintings < ActiveRecord::Migration[7.0] + def change + add_column :printings, :released_by, :string + end +end diff --git a/db/schema.rb b/db/schema.rb index d6e91a99..e02d7a80 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -10,7 +10,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema[7.0].define(version: 2023_10_15_222301) do +ActiveRecord::Schema[7.0].define(version: 2023_10_16_210204) do # These are extensions that must be enabled in order to support this database enable_extension "pgcrypto" enable_extension "plpgsql" @@ -195,6 +195,7 @@ t.datetime "created_at", null: false t.datetime "updated_at", null: false t.integer "position_in_set" + t.string "released_by" end create_table "restrictions", id: :string, force: :cascade do |t| diff --git a/lib/tasks/cards.rake b/lib/tasks/cards.rake index d1248c52..c3c0a570 100644 --- a/lib/tasks/cards.rake +++ b/lib/tasks/cards.rake @@ -313,6 +313,7 @@ namespace :cards do card_id: printing["card_id"], card_set_id: printing["card_set_id"], date_release: card_sets[printing["card_set_id"]].date_release, + released_by: printing["released_by"], ) } From e9598c7811fbe10c3e69d594f7d936b277f1bc6e Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Tue, 17 Oct 2023 12:28:05 +0200 Subject: [PATCH 4/7] Update unified_{card,printing}s views for designed by and released by. --- ...0_update_unified_printings_to_version_5.rb | 9 + ...01245_update_unified_cards_to_version_4.rb | 9 + db/schema.rb | 281 ++++++++------- db/views/unified_cards_v04.sql | 337 ++++++++++++++++++ db/views/unified_printings_v05.sql | 285 +++++++++++++++ 5 files changed, 789 insertions(+), 132 deletions(-) create mode 100644 db/migrate/20231017100710_update_unified_printings_to_version_5.rb create mode 100644 db/migrate/20231017101245_update_unified_cards_to_version_4.rb create mode 100644 db/views/unified_cards_v04.sql create mode 100644 db/views/unified_printings_v05.sql diff --git a/db/migrate/20231017100710_update_unified_printings_to_version_5.rb b/db/migrate/20231017100710_update_unified_printings_to_version_5.rb new file mode 100644 index 00000000..6ad8b1a5 --- /dev/null +++ b/db/migrate/20231017100710_update_unified_printings_to_version_5.rb @@ -0,0 +1,9 @@ +class UpdateUnifiedPrintingsToVersion5 < ActiveRecord::Migration[7.0] + def change + + update_view :unified_printings, + version: 5, + revert_to_version: 4, + materialized: true + end +end diff --git a/db/migrate/20231017101245_update_unified_cards_to_version_4.rb b/db/migrate/20231017101245_update_unified_cards_to_version_4.rb new file mode 100644 index 00000000..7bb88078 --- /dev/null +++ b/db/migrate/20231017101245_update_unified_cards_to_version_4.rb @@ -0,0 +1,9 @@ +class UpdateUnifiedCardsToVersion4 < ActiveRecord::Migration[7.0] + def change + + update_view :unified_cards, + version: 4, + revert_to_version: 3, + materialized: true + end +end diff --git a/db/schema.rb b/db/schema.rb index e02d7a80..5c558357 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -10,7 +10,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema[7.0].define(version: 2023_10_16_210204) do +ActiveRecord::Schema[7.0].define(version: 2023_10_17_101245) do # These are extensions that must be enabled in order to support this database enable_extension "pgcrypto" enable_extension "plpgsql" @@ -371,23 +371,23 @@ add_index "unified_restrictions", ["restriction_id"], name: "index_unified_restrictions_on_restriction_id" add_index "unified_restrictions", ["snapshot_id"], name: "index_unified_restrictions_on_snapshot_id" - create_view "unified_cards", materialized: true, sql_definition: <<-SQL + create_view "unified_printings", materialized: true, sql_definition: <<-SQL WITH card_cycles_summary AS ( SELECT c_1.id, - array_agg(cc.id ORDER BY cc.id) AS card_cycle_ids, - array_agg(lower(cc.name) ORDER BY (lower(cc.name))) AS card_cycle_names + array_agg(cc_1.id ORDER BY cc_1.id) AS card_cycle_ids, + array_agg(lower(cc_1.name) ORDER BY (lower(cc_1.name))) AS card_cycle_names FROM (((cards c_1 JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) - JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) - JOIN card_cycles cc ON (((cc.id)::text = cs.card_cycle_id))) + JOIN card_sets cs_1 ON ((p_1.card_set_id = (cs_1.id)::text))) + JOIN card_cycles cc_1 ON (((cc_1.id)::text = cs_1.card_cycle_id))) GROUP BY c_1.id ), card_sets_summary AS ( SELECT c_1.id, - array_agg(cs.id ORDER BY cs.id) AS card_set_ids, - array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS card_set_names + array_agg(cs_1.id ORDER BY cs_1.id) AS card_set_ids, + array_agg(lower(cs_1.name) ORDER BY (lower(cs_1.name))) AS card_set_names FROM ((cards c_1 JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) - JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) + JOIN card_sets cs_1 ON ((p_1.card_set_id = (cs_1.id)::text))) GROUP BY c_1.id ), card_subtype_ids AS ( SELECT cards_card_subtypes.card_id, @@ -396,21 +396,28 @@ GROUP BY cards_card_subtypes.card_id ), card_subtype_names AS ( SELECT ccs_1.card_id, - array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS lower_card_subtype_names, - array_agg(cs.name ORDER BY cs.name) AS card_subtype_names + array_agg(lower(cs_1.name) ORDER BY (lower(cs_1.name))) AS lower_card_subtype_names, + array_agg(cs_1.name ORDER BY cs_1.name) AS card_subtype_names FROM (cards_card_subtypes ccs_1 - JOIN card_subtypes cs ON ((ccs_1.card_subtype_id = (cs.id)::text))) + JOIN card_subtypes cs_1 ON ((ccs_1.card_subtype_id = (cs_1.id)::text))) GROUP BY ccs_1.card_id ), card_printing_ids AS ( SELECT printings.card_id, array_agg(printings.id ORDER BY printings.date_release DESC) AS printing_ids FROM printings GROUP BY printings.card_id - ), card_release_dates AS ( + ), printing_releasers AS ( SELECT printings.card_id, - min(printings.date_release) AS date_release + array_agg(DISTINCT printings.released_by ORDER BY printings.released_by) AS releasers FROM printings GROUP BY printings.card_id + ), illustrators AS ( + SELECT ip.printing_id, + array_agg(ip.illustrator_id ORDER BY ip.illustrator_id) AS illustrator_ids, + array_agg(i_1.name ORDER BY i_1.name) AS illustrator_names + FROM (illustrators_printings ip + JOIN public.illustrators i_1 ON (((ip.illustrator_id)::text = (i_1.id)::text))) + GROUP BY ip.printing_id ), card_restriction_ids AS ( SELECT unified_restrictions.card_id, array_agg(unified_restrictions.restriction_id ORDER BY unified_restrictions.restriction_id) AS restriction_ids @@ -461,51 +468,56 @@ JOIN snapshots s_1 ON ((cpc_1.card_pool_id = s_1.card_pool_id))) GROUP BY cpc_1.card_id ) - SELECT c.id, - c.title, - c.stripped_title, - c.card_type_id, - c.side_id, - c.faction_id, + SELECT p.id, + p.card_id, + cc.id AS card_cycle_id, + cc.name AS card_cycle_name, + p.card_set_id, + cs.name AS card_set_name, + p.flavor, + p.display_illustrators, + p."position", + p.position_in_set, + p.quantity, + p.date_release, + p.created_at, + p.updated_at, + c.additional_cost, + c.advanceable, c.advancement_requirement, c.agenda_points, c.base_link, + c.card_type_id, c.cost, - c.deck_limit, - c.influence_cost, - c.influence_limit, - c.memory_cost, - c.minimum_deck_size, - c.strength, - c.stripped_text, - c.text, - c.trash_cost, - c.is_unique, - c.display_subtypes, - c.attribution, - c.created_at, - c.updated_at, - c.additional_cost, - c.advanceable, + c.faction_id, c.gains_subroutines, + c.influence_cost, c.interrupt, + c.is_unique, c.link_provided, + c.memory_cost, c.mu_provided, c.num_printed_subroutines, c.on_encounter_effect, c.performs_trace, c.recurring_credits_provided, - c.rez_effect, + c.side_id, + c.strength, + c.stripped_text, + c.stripped_title, c.trash_ability, + c.trash_cost, COALESCE(csi.card_subtype_ids, ARRAY[]::text[]) AS card_subtype_ids, COALESCE(csn.lower_card_subtype_names, ARRAY[]::text[]) AS lower_card_subtype_names, COALESCE(csn.card_subtype_names, ARRAY[]::text[]) AS card_subtype_names, - p.printing_ids, - array_length(p.printing_ids, 1) AS num_printings, - ccs.card_cycle_ids, - ccs.card_cycle_names, - css.card_set_ids, - css.card_set_names, + cp.printing_ids, + array_length(cp.printing_ids, 1) AS num_printings, + COALESCE(ccs.card_cycle_ids, (ARRAY[]::text[])::character varying[]) AS card_cycle_ids, + COALESCE(ccs.card_cycle_names, ARRAY[]::text[]) AS card_cycle_names, + COALESCE(css.card_set_ids, (ARRAY[]::text[])::character varying[]) AS card_set_ids, + COALESCE(css.card_set_names, ARRAY[]::text[]) AS card_set_names, + COALESCE(i.illustrator_ids, (ARRAY[]::text[])::character varying[]) AS illustrator_ids, + COALESCE(i.illustrator_names, (ARRAY[]::text[])::character varying[]) AS illustrator_names, COALESCE(r.restriction_ids, (ARRAY[]::text[])::character varying[]) AS restriction_ids, (r.restriction_ids IS NOT NULL) AS in_restriction, COALESCE(r_b.restrictions_banned, ARRAY[]::text[]) AS restrictions_banned, @@ -516,42 +528,60 @@ COALESCE(f.format_ids, ARRAY[]::text[]) AS format_ids, COALESCE(cpc.card_pool_ids, ARRAY[]::text[]) AS card_pool_ids, COALESCE(s.snapshot_ids, (ARRAY[]::text[])::character varying[]) AS snapshot_ids, - crd.date_release - FROM (((((((((((((((cards c - JOIN card_printing_ids p ON (((c.id)::text = p.card_id))) + c.attribution, + c.deck_limit, + c.display_subtypes, + c.influence_limit, + c.minimum_deck_size, + c.rez_effect, + c.text, + c.title, + c.designed_by, + p.released_by, + pr.releasers AS printings_released_by + FROM (((((((((((((((((((printings p + JOIN cards c ON ((p.card_id = (c.id)::text))) JOIN card_cycles_summary ccs ON (((c.id)::text = (ccs.id)::text))) JOIN card_sets_summary css ON (((c.id)::text = (css.id)::text))) + JOIN card_sets cs ON ((p.card_set_id = (cs.id)::text))) + JOIN card_cycles cc ON ((cs.card_cycle_id = (cc.id)::text))) LEFT JOIN card_subtype_ids csi ON (((c.id)::text = csi.card_id))) LEFT JOIN card_subtype_names csn ON (((c.id)::text = csn.card_id))) - LEFT JOIN card_restriction_ids r ON (((c.id)::text = (r.card_id)::text))) - LEFT JOIN restrictions_banned_summary r_b ON (((c.id)::text = r_b.card_id))) - LEFT JOIN restrictions_global_penalty_summary r_g_p ON (((c.id)::text = r_g_p.card_id))) - LEFT JOIN restrictions_points_summary r_p ON (((c.id)::text = r_p.card_id))) - LEFT JOIN restrictions_restricted_summary r_r ON (((c.id)::text = r_r.card_id))) - LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON (((c.id)::text = r_u_f_c.card_id))) - LEFT JOIN format_ids f ON (((c.id)::text = f.card_id))) - LEFT JOIN card_pool_ids cpc ON (((c.id)::text = cpc.card_id))) - LEFT JOIN snapshot_ids s ON (((c.id)::text = s.card_id))) - LEFT JOIN card_release_dates crd ON (((c.id)::text = crd.card_id))) - GROUP BY c.id, c.title, c.stripped_title, c.card_type_id, c.side_id, c.faction_id, c.advancement_requirement, c.agenda_points, c.base_link, c.cost, c.deck_limit, c.influence_cost, c.influence_limit, c.memory_cost, c.minimum_deck_size, c.strength, c.stripped_text, c.text, c.trash_cost, c.is_unique, c.display_subtypes, c.attribution, c.created_at, c.updated_at, c.additional_cost, c.advanceable, c.gains_subroutines, c.interrupt, c.link_provided, c.mu_provided, c.num_printed_subroutines, c.on_encounter_effect, c.performs_trace, c.recurring_credits_provided, c.rez_effect, c.trash_ability, csi.card_subtype_ids, csn.lower_card_subtype_names, csn.card_subtype_names, p.printing_ids, ccs.card_cycle_ids, ccs.card_cycle_names, css.card_set_ids, css.card_set_names, r.restriction_ids, r_b.restrictions_banned, r_g_p.restrictions_global_penalty, r_p.restrictions_points, r_r.restrictions_restricted, r_u_f_c.restrictions_universal_faction_cost, f.format_ids, cpc.card_pool_ids, s.snapshot_ids, crd.date_release; + JOIN card_printing_ids cp ON ((p.card_id = cp.card_id))) + JOIN printing_releasers pr ON ((p.card_id = pr.card_id))) + LEFT JOIN illustrators i ON (((p.id)::text = (i.printing_id)::text))) + LEFT JOIN card_restriction_ids r ON ((p.card_id = (r.card_id)::text))) + LEFT JOIN restrictions_banned_summary r_b ON ((p.card_id = r_b.card_id))) + LEFT JOIN restrictions_global_penalty_summary r_g_p ON ((p.card_id = r_g_p.card_id))) + LEFT JOIN restrictions_points_summary r_p ON ((p.card_id = r_p.card_id))) + LEFT JOIN restrictions_restricted_summary r_r ON ((p.card_id = r_r.card_id))) + LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON ((p.card_id = r_u_f_c.card_id))) + LEFT JOIN format_ids f ON ((p.card_id = f.card_id))) + LEFT JOIN card_pool_ids cpc ON ((p.card_id = cpc.card_id))) + LEFT JOIN snapshot_ids s ON ((p.card_id = s.card_id))); SQL - create_view "unified_printings", materialized: true, sql_definition: <<-SQL + create_view "unified_cards", materialized: true, sql_definition: <<-SQL WITH card_cycles_summary AS ( SELECT c_1.id, - array_agg(cc_1.id ORDER BY cc_1.id) AS card_cycle_ids, - array_agg(lower(cc_1.name) ORDER BY (lower(cc_1.name))) AS card_cycle_names + array_agg(cc.id ORDER BY cc.id) AS card_cycle_ids, + array_agg(lower(cc.name) ORDER BY (lower(cc.name))) AS card_cycle_names FROM (((cards c_1 JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) - JOIN card_sets cs_1 ON ((p_1.card_set_id = (cs_1.id)::text))) - JOIN card_cycles cc_1 ON (((cc_1.id)::text = cs_1.card_cycle_id))) + JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) + JOIN card_cycles cc ON (((cc.id)::text = cs.card_cycle_id))) GROUP BY c_1.id + ), printing_releasers AS ( + SELECT printings.card_id, + array_agg(DISTINCT printings.released_by ORDER BY printings.released_by) AS releasers + FROM printings + GROUP BY printings.card_id ), card_sets_summary AS ( SELECT c_1.id, - array_agg(cs_1.id ORDER BY cs_1.id) AS card_set_ids, - array_agg(lower(cs_1.name) ORDER BY (lower(cs_1.name))) AS card_set_names + array_agg(cs.id ORDER BY cs.id) AS card_set_ids, + array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS card_set_names FROM ((cards c_1 JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) - JOIN card_sets cs_1 ON ((p_1.card_set_id = (cs_1.id)::text))) + JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) GROUP BY c_1.id ), card_subtype_ids AS ( SELECT cards_card_subtypes.card_id, @@ -560,23 +590,21 @@ GROUP BY cards_card_subtypes.card_id ), card_subtype_names AS ( SELECT ccs_1.card_id, - array_agg(lower(cs_1.name) ORDER BY (lower(cs_1.name))) AS lower_card_subtype_names, - array_agg(cs_1.name ORDER BY cs_1.name) AS card_subtype_names + array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS lower_card_subtype_names, + array_agg(cs.name ORDER BY cs.name) AS card_subtype_names FROM (cards_card_subtypes ccs_1 - JOIN card_subtypes cs_1 ON ((ccs_1.card_subtype_id = (cs_1.id)::text))) + JOIN card_subtypes cs ON ((ccs_1.card_subtype_id = (cs.id)::text))) GROUP BY ccs_1.card_id ), card_printing_ids AS ( SELECT printings.card_id, array_agg(printings.id ORDER BY printings.date_release DESC) AS printing_ids FROM printings GROUP BY printings.card_id - ), illustrators AS ( - SELECT ip.printing_id, - array_agg(ip.illustrator_id ORDER BY ip.illustrator_id) AS illustrator_ids, - array_agg(i_1.name ORDER BY i_1.name) AS illustrator_names - FROM (illustrators_printings ip - JOIN public.illustrators i_1 ON (((ip.illustrator_id)::text = (i_1.id)::text))) - GROUP BY ip.printing_id + ), card_release_dates AS ( + SELECT printings.card_id, + min(printings.date_release) AS date_release + FROM printings + GROUP BY printings.card_id ), card_restriction_ids AS ( SELECT unified_restrictions.card_id, array_agg(unified_restrictions.restriction_id ORDER BY unified_restrictions.restriction_id) AS restriction_ids @@ -627,56 +655,51 @@ JOIN snapshots s_1 ON ((cpc_1.card_pool_id = s_1.card_pool_id))) GROUP BY cpc_1.card_id ) - SELECT p.id, - p.card_id, - cc.id AS card_cycle_id, - cc.name AS card_cycle_name, - p.card_set_id, - cs.name AS card_set_name, - p.flavor, - p.display_illustrators, - p."position", - p.position_in_set, - p.quantity, - p.date_release, - p.created_at, - p.updated_at, - c.additional_cost, - c.advanceable, + SELECT c.id, + c.title, + c.stripped_title, + c.card_type_id, + c.side_id, + c.faction_id, c.advancement_requirement, c.agenda_points, c.base_link, - c.card_type_id, c.cost, - c.faction_id, - c.gains_subroutines, + c.deck_limit, c.influence_cost, - c.interrupt, + c.influence_limit, + c.memory_cost, + c.minimum_deck_size, + c.strength, + c.stripped_text, + c.text, + c.trash_cost, c.is_unique, + c.display_subtypes, + c.attribution, + c.created_at, + c.updated_at, + c.additional_cost, + c.advanceable, + c.gains_subroutines, + c.interrupt, c.link_provided, - c.memory_cost, c.mu_provided, c.num_printed_subroutines, c.on_encounter_effect, c.performs_trace, c.recurring_credits_provided, - c.side_id, - c.strength, - c.stripped_text, - c.stripped_title, + c.rez_effect, c.trash_ability, - c.trash_cost, COALESCE(csi.card_subtype_ids, ARRAY[]::text[]) AS card_subtype_ids, COALESCE(csn.lower_card_subtype_names, ARRAY[]::text[]) AS lower_card_subtype_names, COALESCE(csn.card_subtype_names, ARRAY[]::text[]) AS card_subtype_names, - cp.printing_ids, - array_length(cp.printing_ids, 1) AS num_printings, - COALESCE(ccs.card_cycle_ids, (ARRAY[]::text[])::character varying[]) AS card_cycle_ids, - COALESCE(ccs.card_cycle_names, ARRAY[]::text[]) AS card_cycle_names, - COALESCE(css.card_set_ids, (ARRAY[]::text[])::character varying[]) AS card_set_ids, - COALESCE(css.card_set_names, ARRAY[]::text[]) AS card_set_names, - COALESCE(i.illustrator_ids, (ARRAY[]::text[])::character varying[]) AS illustrator_ids, - COALESCE(i.illustrator_names, (ARRAY[]::text[])::character varying[]) AS illustrator_names, + p.printing_ids, + array_length(p.printing_ids, 1) AS num_printings, + ccs.card_cycle_ids, + ccs.card_cycle_names, + css.card_set_ids, + css.card_set_names, COALESCE(r.restriction_ids, (ARRAY[]::text[])::character varying[]) AS restriction_ids, (r.restriction_ids IS NOT NULL) AS in_restriction, COALESCE(r_b.restrictions_banned, ARRAY[]::text[]) AS restrictions_banned, @@ -687,32 +710,26 @@ COALESCE(f.format_ids, ARRAY[]::text[]) AS format_ids, COALESCE(cpc.card_pool_ids, ARRAY[]::text[]) AS card_pool_ids, COALESCE(s.snapshot_ids, (ARRAY[]::text[])::character varying[]) AS snapshot_ids, - c.attribution, - c.deck_limit, - c.display_subtypes, - c.influence_limit, - c.minimum_deck_size, - c.rez_effect, - c.text, - c.title - FROM ((((((((((((((((((printings p - JOIN cards c ON ((p.card_id = (c.id)::text))) + crd.date_release, + c.designed_by, + pr.releasers AS printings_released_by + FROM ((((((((((((((((cards c + JOIN card_printing_ids p ON (((c.id)::text = p.card_id))) JOIN card_cycles_summary ccs ON (((c.id)::text = (ccs.id)::text))) JOIN card_sets_summary css ON (((c.id)::text = (css.id)::text))) - JOIN card_sets cs ON ((p.card_set_id = (cs.id)::text))) - JOIN card_cycles cc ON ((cs.card_cycle_id = (cc.id)::text))) + JOIN printing_releasers pr ON (((c.id)::text = pr.card_id))) LEFT JOIN card_subtype_ids csi ON (((c.id)::text = csi.card_id))) LEFT JOIN card_subtype_names csn ON (((c.id)::text = csn.card_id))) - JOIN card_printing_ids cp ON ((p.card_id = cp.card_id))) - LEFT JOIN illustrators i ON (((p.id)::text = (i.printing_id)::text))) - LEFT JOIN card_restriction_ids r ON ((p.card_id = (r.card_id)::text))) - LEFT JOIN restrictions_banned_summary r_b ON ((p.card_id = r_b.card_id))) - LEFT JOIN restrictions_global_penalty_summary r_g_p ON ((p.card_id = r_g_p.card_id))) - LEFT JOIN restrictions_points_summary r_p ON ((p.card_id = r_p.card_id))) - LEFT JOIN restrictions_restricted_summary r_r ON ((p.card_id = r_r.card_id))) - LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON ((p.card_id = r_u_f_c.card_id))) - LEFT JOIN format_ids f ON ((p.card_id = f.card_id))) - LEFT JOIN card_pool_ids cpc ON ((p.card_id = cpc.card_id))) - LEFT JOIN snapshot_ids s ON ((p.card_id = s.card_id))); + LEFT JOIN card_restriction_ids r ON (((c.id)::text = (r.card_id)::text))) + LEFT JOIN restrictions_banned_summary r_b ON (((c.id)::text = r_b.card_id))) + LEFT JOIN restrictions_global_penalty_summary r_g_p ON (((c.id)::text = r_g_p.card_id))) + LEFT JOIN restrictions_points_summary r_p ON (((c.id)::text = r_p.card_id))) + LEFT JOIN restrictions_restricted_summary r_r ON (((c.id)::text = r_r.card_id))) + LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON (((c.id)::text = r_u_f_c.card_id))) + LEFT JOIN format_ids f ON (((c.id)::text = f.card_id))) + LEFT JOIN card_pool_ids cpc ON (((c.id)::text = cpc.card_id))) + LEFT JOIN snapshot_ids s ON (((c.id)::text = s.card_id))) + LEFT JOIN card_release_dates crd ON (((c.id)::text = crd.card_id))) + GROUP BY c.id, c.title, c.stripped_title, c.card_type_id, c.side_id, c.faction_id, c.advancement_requirement, c.agenda_points, c.base_link, c.cost, c.deck_limit, c.influence_cost, c.influence_limit, c.memory_cost, c.minimum_deck_size, c.strength, c.stripped_text, c.text, c.trash_cost, c.is_unique, c.display_subtypes, c.attribution, c.created_at, c.updated_at, c.additional_cost, c.advanceable, c.gains_subroutines, c.interrupt, c.link_provided, c.mu_provided, c.num_printed_subroutines, c.on_encounter_effect, c.performs_trace, c.recurring_credits_provided, c.rez_effect, c.trash_ability, csi.card_subtype_ids, csn.lower_card_subtype_names, csn.card_subtype_names, p.printing_ids, ccs.card_cycle_ids, ccs.card_cycle_names, css.card_set_ids, css.card_set_names, r.restriction_ids, r_b.restrictions_banned, r_g_p.restrictions_global_penalty, r_p.restrictions_points, r_r.restrictions_restricted, r_u_f_c.restrictions_universal_faction_cost, f.format_ids, cpc.card_pool_ids, s.snapshot_ids, crd.date_release, pr.releasers; SQL end diff --git a/db/views/unified_cards_v04.sql b/db/views/unified_cards_v04.sql new file mode 100644 index 00000000..74c23493 --- /dev/null +++ b/db/views/unified_cards_v04.sql @@ -0,0 +1,337 @@ +WITH card_cycles_summary AS ( + SELECT + c.id, + ARRAY_AGG( + cc.id ORDER BY cc.id + ) as card_cycle_ids, + ARRAY_AGG( + LOWER(cc.name) ORDER BY LOWER(cc.name) + ) as card_cycle_names + FROM + cards c + JOIN printings p ON c.id = p.card_id + JOIN card_sets cs ON p.card_set_id = cs.id + JOIN card_cycles cc ON cc.id = cs.card_cycle_id + GROUP BY + c.id +), +printing_releasers AS ( + SELECT + card_id, + ARRAY_AGG(DISTINCT released_by ORDER BY released_by) as releasers + FROM + printings + GROUP BY + card_id +), +card_sets_summary AS ( + SELECT + c.id, + ARRAY_AGG( + cs.id ORDER BY cs.id + ) as card_set_ids, + ARRAY_AGG( + LOWER(cs.name) ORDER BY LOWER(cs.name) + ) as card_set_names + FROM + cards c + JOIN printings p ON c.id = p.card_id + JOIN card_sets cs ON p.card_set_id = cs.id + GROUP BY + c.id +), +card_subtype_ids AS ( + SELECT + card_id, + ARRAY_AGG( + card_subtype_id + ORDER BY + 1 + ) as card_subtype_ids + FROM + cards_card_subtypes + GROUP BY + card_id +), +card_subtype_names AS ( + SELECT + ccs.card_id, + -- lower used for filtering + ARRAY_AGG( + LOWER(cs.name) ORDER BY LOWER(cs.name) + ) as lower_card_subtype_names, + -- proper case used for display + ARRAY_AGG( + cs.name ORDER BY cs.name + ) as card_subtype_names + FROM + cards_card_subtypes ccs + JOIN card_subtypes cs ON ccs.card_subtype_id = cs.id + GROUP BY + ccs.card_id +), +card_printing_ids AS ( + SELECT + card_id, + ARRAY_AGG( + id ORDER BY date_release DESC + ) as printing_ids + FROM + printings + GROUP BY + card_id +), +card_release_dates AS ( + SELECT + card_id, + MIN(date_release) as date_release + FROM + printings + GROUP BY + card_id +), +card_restriction_ids AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restriction_ids + FROM + unified_restrictions + WHERE + in_restriction + GROUP BY + 1 +), +restrictions_banned_summary AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restrictions_banned + FROM + restrictions_cards_banned + GROUP BY + card_id +), +restrictions_global_penalty_summary AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restrictions_global_penalty + FROM + restrictions_cards_global_penalty + GROUP BY + card_id +), +restrictions_points_summary AS ( + SELECT + card_id, + ARRAY_AGG( + CONCAT(restriction_id, '=', CAST (value AS text)) + ORDER BY CONCAT(restriction_id, '=', CAST (value AS text)) + ) as restrictions_points + FROM + restrictions_cards_points + GROUP BY + card_id +), +restrictions_restricted_summary AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restrictions_restricted + FROM + restrictions_cards_restricted + GROUP BY + card_id +), +restrictions_universal_faction_cost_summary AS ( + SELECT + card_id, + ARRAY_AGG( + CONCAT(restriction_id, '=', CAST (value AS text)) + ORDER BY CONCAT(restriction_id, '=', CAST (value AS text)) + ) as restrictions_universal_faction_cost + FROM + restrictions_cards_universal_faction_cost + GROUP BY + card_id +), +format_ids AS ( + SELECT + cpc.card_id, + ARRAY_AGG( + DISTINCT s.format_id ORDER BY s.format_id + ) as format_ids + FROM + card_pools_cards cpc + JOIN snapshots s ON cpc.card_pool_id = s.card_pool_id + GROUP BY + cpc.card_id +), +card_pool_ids AS ( + SELECT + cpc.card_id, + ARRAY_AGG( + DISTINCT s.card_pool_id ORDER BY s.card_pool_id + ) as card_pool_ids + FROM + card_pools_cards cpc + JOIN snapshots s ON cpc.card_pool_id = s.card_pool_id + GROUP BY + cpc.card_id +), +snapshot_ids AS ( + SELECT + cpc.card_id, + ARRAY_AGG( + DISTINCT s.id ORDER BY s.id + ) as snapshot_ids + FROM + card_pools_cards cpc + JOIN snapshots s ON cpc.card_pool_id = s.card_pool_id + GROUP BY + cpc.card_id +) +SELECT + c.id as id, + c.title, + c.stripped_title, + c.card_type_id, + c.side_id, + c.faction_id, + c.advancement_requirement, + c.agenda_points, + c.base_link, + c.cost, + c.deck_limit, + c.influence_cost, + c.influence_limit, + c.memory_cost, + c.minimum_deck_size, + c.strength, + c.stripped_text, + c.text, + c.trash_cost, + c.is_unique, + c.display_subtypes, + c.attribution, + c.created_at, + c.updated_at, + c.additional_cost, + c.advanceable, + c.gains_subroutines, + c.interrupt, + c.link_provided, + c.mu_provided, + c.num_printed_subroutines, + c.on_encounter_effect, + c.performs_trace, + c.recurring_credits_provided, + c.rez_effect, + c.trash_ability, + COALESCE(csi.card_subtype_ids, ARRAY [] :: text []) as card_subtype_ids, + COALESCE(csn.lower_card_subtype_names, ARRAY [] :: text []) as lower_card_subtype_names, + COALESCE(csn.card_subtype_names, ARRAY [] :: text []) as card_subtype_names, + p.printing_ids, + ARRAY_LENGTH(p.printing_ids, 1) AS num_printings, + ccs.card_cycle_ids, + ccs.card_cycle_names, + css.card_set_ids, + css.card_set_names, + COALESCE(r.restriction_ids, ARRAY [] :: text []) as restriction_ids, + r.restriction_ids IS NOT NULL as in_restriction, + COALESCE(r_b.restrictions_banned, ARRAY [] :: text []) as restrictions_banned, + COALESCE( + r_g_p.restrictions_global_penalty, + ARRAY [] :: text [] + ) as restrictions_global_penalty, + COALESCE(r_p.restrictions_points, ARRAY [] :: text []) as restrictions_points, + COALESCE(r_r.restrictions_restricted, ARRAY [] :: text []) as restrictions_restricted, + COALESCE( + r_u_f_c.restrictions_universal_faction_cost, + ARRAY [] :: text [] + ) as restrictions_universal_faction_cost, + COALESCE(f.format_ids, ARRAY [] :: text []) as format_ids, + COALESCE(cpc.card_pool_ids, ARRAY [] :: text []) as card_pool_ids, + COALESCE(s.snapshot_ids, ARRAY [] :: text []) as snapshot_ids, + crd.date_release, + c.designed_by, + pr.releasers as printings_released_by +FROM + cards c + JOIN card_printing_ids p ON c.id = p.card_id + JOIN card_cycles_summary ccs ON c.id = ccs.id + JOIN card_sets_summary css ON c.id = css.id + INNER JOIN printing_releasers pr ON c.id = pr.card_id + LEFT JOIN card_subtype_ids csi ON c.id = csi.card_id + LEFT JOIN card_subtype_names csn ON c.id = csn.card_id + LEFT JOIN card_restriction_ids r ON c.id = r.card_id + LEFT JOIN restrictions_banned_summary r_b ON c.id = r_b.card_id + LEFT JOIN restrictions_global_penalty_summary r_g_p ON c.id = r_g_p.card_id + LEFT JOIN restrictions_points_summary r_p ON c.id = r_p.card_id + LEFT JOIN restrictions_restricted_summary r_r ON c.id = r_r.card_id + LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON c.id = r_u_f_c.card_id + LEFT JOIN format_ids f ON c.id = f.card_id + LEFT JOIN card_pool_ids cpc ON c.id = cpc.card_id + LEFT JOIN snapshot_ids s ON c.id = s.card_id + LEFT JOIN card_release_dates crd ON c.id = crd.card_id +GROUP BY + c.id, + c.title, + c.stripped_title, + c.card_type_id, + c.side_id, + c.faction_id, + c.advancement_requirement, + c.agenda_points, + c.base_link, + c.cost, + c.deck_limit, + c.influence_cost, + c.influence_limit, + c.memory_cost, + c.minimum_deck_size, + c.strength, + c.stripped_text, + c.text, + c.trash_cost, + c.is_unique, + c.display_subtypes, + c.attribution, + c.created_at, + c.updated_at, + c.additional_cost, + c.advanceable, + c.gains_subroutines, + c.interrupt, + c.link_provided, + c.mu_provided, + c.num_printed_subroutines, + c.on_encounter_effect, + c.performs_trace, + c.recurring_credits_provided, + c.rez_effect, + c.trash_ability, + csi.card_subtype_ids, + csn.lower_card_subtype_names, + csn.card_subtype_names, + p.printing_ids, + ccs.card_cycle_ids, + ccs.card_cycle_names, + css.card_set_ids, + css.card_set_names, + r.restriction_ids, + r_b.restrictions_banned, + r_g_p.restrictions_global_penalty, + r_p.restrictions_points, + r_r.restrictions_restricted, + r_u_f_c.restrictions_universal_faction_cost, + f.format_ids, + cpc.card_pool_ids, + s.snapshot_ids, + crd.date_release, + pr.releasers; diff --git a/db/views/unified_printings_v05.sql b/db/views/unified_printings_v05.sql new file mode 100644 index 00000000..4c81acce --- /dev/null +++ b/db/views/unified_printings_v05.sql @@ -0,0 +1,285 @@ +WITH +card_cycles_summary AS ( + SELECT + c.id, + ARRAY_AGG( + cc.id ORDER BY cc.id + ) as card_cycle_ids, + ARRAY_AGG( + LOWER(cc.name) ORDER BY LOWER(cc.name) + ) as card_cycle_names + FROM + cards c + JOIN printings p ON c.id = p.card_id + JOIN card_sets cs ON p.card_set_id = cs.id + JOIN card_cycles cc ON cc.id = cs.card_cycle_id + GROUP BY + c.id +), +card_sets_summary AS ( + SELECT + c.id, + ARRAY_AGG( + cs.id ORDER BY cs.id + ) as card_set_ids, + ARRAY_AGG( + LOWER(cs.name) ORDER BY LOWER(cs.name) + ) as card_set_names + FROM + cards c + JOIN printings p ON c.id = p.card_id + JOIN card_sets cs ON p.card_set_id = cs.id + GROUP BY + c.id +), +card_subtype_ids AS ( + SELECT + card_id, + ARRAY_AGG(card_subtype_id ORDER BY 1) as card_subtype_ids + FROM + cards_card_subtypes + GROUP BY + card_id +), +card_subtype_names AS ( + SELECT + ccs.card_id, + -- lower used for filtering + ARRAY_AGG(LOWER(cs.name) ORDER BY LOWER(cs.name)) as lower_card_subtype_names, + -- proper case used for display + ARRAY_AGG( + cs.name ORDER BY cs.name + ) as card_subtype_names + FROM + cards_card_subtypes ccs + JOIN card_subtypes cs ON ccs.card_subtype_id = cs.id + GROUP BY + ccs.card_id +), +card_printing_ids AS ( + SELECT + card_id, + ARRAY_AGG(id ORDER BY date_release DESC) as printing_ids + FROM + printings + GROUP BY + card_id +), +printing_releasers AS ( + SELECT + card_id, + ARRAY_AGG(DISTINCT released_by ORDER BY released_by) as releasers + FROM + printings + GROUP BY + card_id +), +illustrators AS ( + SELECT + ip.printing_id, + ARRAY_AGG(ip.illustrator_id ORDER BY ip.illustrator_id) as illustrator_ids, + ARRAY_AGG(i.name ORDER BY i.name) as illustrator_names + FROM + illustrators_printings ip JOIN illustrators i ON ip.illustrator_id = i.id + GROUP BY + ip.printing_id +), +card_restriction_ids AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restriction_ids + FROM + unified_restrictions + WHERE + in_restriction + GROUP BY + 1 +), +restrictions_banned_summary AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restrictions_banned + FROM + restrictions_cards_banned + GROUP BY + card_id +), +restrictions_global_penalty_summary AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restrictions_global_penalty + FROM + restrictions_cards_global_penalty + GROUP BY + card_id +), +restrictions_points_summary AS ( + SELECT + card_id, + ARRAY_AGG( + CONCAT(restriction_id, '=', CAST (value AS text)) + ORDER BY CONCAT(restriction_id, '=', CAST (value AS text)) + ) as restrictions_points + FROM + restrictions_cards_points + GROUP BY + card_id +), +restrictions_restricted_summary AS ( + SELECT + card_id, + ARRAY_AGG( + restriction_id ORDER BY restriction_id + ) as restrictions_restricted + FROM + restrictions_cards_restricted + GROUP BY + card_id +), +restrictions_universal_faction_cost_summary AS ( + SELECT + card_id, + ARRAY_AGG( + CONCAT(restriction_id, '=', CAST (value AS text)) + ORDER BY CONCAT(restriction_id, '=', CAST (value AS text)) + ) as restrictions_universal_faction_cost + FROM + restrictions_cards_universal_faction_cost + GROUP BY + card_id +), +format_ids AS ( + SELECT + cpc.card_id, + ARRAY_AGG( + DISTINCT s.format_id ORDER BY s.format_id + ) as format_ids + FROM + card_pools_cards cpc + JOIN snapshots s ON cpc.card_pool_id = s.card_pool_id + GROUP BY + cpc.card_id +), +card_pool_ids AS ( + SELECT + cpc.card_id, + ARRAY_AGG( + DISTINCT s.card_pool_id ORDER BY s.card_pool_id + ) as card_pool_ids + FROM + card_pools_cards cpc + JOIN snapshots s ON cpc.card_pool_id = s.card_pool_id + GROUP BY + cpc.card_id +), +snapshot_ids AS ( + SELECT + cpc.card_id, + ARRAY_AGG( + DISTINCT s.id ORDER BY s.id + ) as snapshot_ids + FROM + card_pools_cards cpc + JOIN snapshots s ON cpc.card_pool_id = s.card_pool_id + GROUP BY + cpc.card_id +) +SELECT + p.id, + p.card_id, + cc.id as card_cycle_id, + cc.name as card_cycle_name, + p.card_set_id, + cs.name as card_set_name, + p.flavor, + p.display_illustrators, + p.position, + p.position_in_set, + p.quantity, + p.date_release, + p.created_at, + p.updated_at, + c.additional_cost, + c.advanceable, + c.advancement_requirement, + c.agenda_points, + c.base_link, + c.card_type_id, + c.cost, + c.faction_id, + c.gains_subroutines, + c.influence_cost, + c.interrupt, + c.is_unique, + c.link_provided, + c.memory_cost, + c.mu_provided, + c.num_printed_subroutines, + c.on_encounter_effect, + c.performs_trace, + c.recurring_credits_provided, + c.side_id, + c.strength, + c.stripped_text, + c.stripped_title, + c.trash_ability, + c.trash_cost, + COALESCE(csi.card_subtype_ids, ARRAY [] :: text []) as card_subtype_ids, + COALESCE(csn.lower_card_subtype_names, ARRAY [] :: text []) as lower_card_subtype_names, + COALESCE(csn.card_subtype_names, ARRAY [] :: text []) as card_subtype_names, + cp.printing_ids, + ARRAY_LENGTH(cp.printing_ids, 1) AS num_printings, + COALESCE(ccs.card_cycle_ids, ARRAY [] :: text []) as card_cycle_ids, + COALESCE(ccs.card_cycle_names, ARRAY [] :: text []) as card_cycle_names, + COALESCE(css.card_set_ids, ARRAY [] :: text []) as card_set_ids, + COALESCE(css.card_set_names, ARRAY [] :: text []) as card_set_names, + COALESCE(i.illustrator_ids, ARRAY [] :: text []) as illustrator_ids, + COALESCE(i.illustrator_names, ARRAY [] :: text []) as illustrator_names, + COALESCE(r.restriction_ids, ARRAY [] :: text []) as restriction_ids, + r.restriction_ids IS NOT NULL as in_restriction, + COALESCE(r_b.restrictions_banned, ARRAY [] :: text []) as restrictions_banned, + COALESCE(r_g_p.restrictions_global_penalty, ARRAY [] :: text []) as restrictions_global_penalty, + COALESCE(r_p.restrictions_points, ARRAY [] :: text []) as restrictions_points, + COALESCE(r_r.restrictions_restricted, ARRAY [] :: text []) as restrictions_restricted, + COALESCE(r_u_f_c.restrictions_universal_faction_cost, ARRAY [] :: text []) as restrictions_universal_faction_cost, + COALESCE(f.format_ids, ARRAY [] :: text []) as format_ids, + COALESCE(cpc.card_pool_ids, ARRAY [] :: text []) as card_pool_ids, + COALESCE(s.snapshot_ids, ARRAY [] :: text []) as snapshot_ids, + c.attribution, + c.deck_limit, + c.display_subtypes, + c.influence_limit, + c.minimum_deck_size, + c.rez_effect, + c.text, + c.title, + c.designed_by, + p.released_by, + pr.releasers as printings_released_by +FROM + printings p + INNER JOIN cards c ON p.card_id = c.id + JOIN card_cycles_summary ccs ON c.id = ccs.id + JOIN card_sets_summary css ON c.id = css.id + INNER JOIN card_sets cs ON p.card_set_id = cs.id + INNER JOIN card_cycles cc ON cs.card_cycle_id = cc.id + LEFT JOIN card_subtype_ids csi ON c.id = csi.card_id + LEFT JOIN card_subtype_names csn ON c.id = csn.card_id + INNER JOIN card_printing_ids cp ON p.card_id = cp.card_id + INNER JOIN printing_releasers pr ON p.card_id = pr.card_id + LEFT JOIN illustrators i ON p.id = i.printing_id + LEFT JOIN card_restriction_ids r ON p.card_id = r.card_id + LEFT JOIN restrictions_banned_summary r_b ON p.card_id = r_b.card_id + LEFT JOIN restrictions_global_penalty_summary r_g_p ON p.card_id = r_g_p.card_id + LEFT JOIN restrictions_points_summary r_p ON p.card_id = r_p.card_id + LEFT JOIN restrictions_restricted_summary r_r ON p.card_id = r_r.card_id + LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON p.card_id = r_u_f_c.card_id + LEFT JOIN format_ids f ON p.card_id = f.card_id + LEFT JOIN card_pool_ids cpc ON p.card_id = cpc.card_id + LEFT JOIN snapshot_ids s ON p.card_id = s.card_id From 23d78553ec31ab6ab7cd9a731a37b0d18c9194d8 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Tue, 17 Oct 2023 12:33:23 +0200 Subject: [PATCH 5/7] End view definition with semicolon. --- db/views/unified_printings_v05.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/db/views/unified_printings_v05.sql b/db/views/unified_printings_v05.sql index 4c81acce..7322817c 100644 --- a/db/views/unified_printings_v05.sql +++ b/db/views/unified_printings_v05.sql @@ -283,3 +283,4 @@ FROM LEFT JOIN format_ids f ON p.card_id = f.card_id LEFT JOIN card_pool_ids cpc ON p.card_id = cpc.card_id LEFT JOIN snapshot_ids s ON p.card_id = s.card_id +; From a23cc22ad53c38bfa714250178bb3ccfb1b83436 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Tue, 17 Oct 2023 12:40:54 +0200 Subject: [PATCH 6/7] Expose {design,releas}ed_by and printings_released_by to card and printing resources. --- app/resources/api/v3/public/card_resource.rb | 2 ++ app/resources/api/v3/public/printing_resource.rb | 3 ++- 2 files changed, 4 insertions(+), 1 deletion(-) diff --git a/app/resources/api/v3/public/card_resource.rb b/app/resources/api/v3/public/card_resource.rb index 307c3235..6d2edabe 100644 --- a/app/resources/api/v3/public/card_resource.rb +++ b/app/resources/api/v3/public/card_resource.rb @@ -13,6 +13,7 @@ class Api::V3::Public::CardResource < JSONAPI::Resource attributes :date_release, :restriction_ids, :strength, :stripped_text, :text, :trash_cost, :is_unique attributes :card_subtype_ids, :display_subtypes, :attribution, :updated_at attributes :format_ids, :card_pool_ids, :snapshot_ids, :card_cycle_ids, :card_set_ids + attributes :designed_by, :printings_released_by # Synthesized attributes attributes :card_abilities, :latest_printing_id, :restrictions @@ -52,6 +53,7 @@ def restrictions filters :title, :card_type_id, :side_id, :faction_id, :advancement_requirement filters :agenda_points, :base_link, :cost, :deck_limit, :influence_cost filters :influence_limit, :memory_cost, :minimum_deck_size, :strength, :trash_cost, :is_unique + filters :designed_by filter :search, apply: ->(records, value, _options) { query_builder = CardSearchQueryBuilder.new(value[0]) diff --git a/app/resources/api/v3/public/printing_resource.rb b/app/resources/api/v3/public/printing_resource.rb index acd695a9..13159b8c 100644 --- a/app/resources/api/v3/public/printing_resource.rb +++ b/app/resources/api/v3/public/printing_resource.rb @@ -22,6 +22,7 @@ class Api::V3::Public::PrintingResource < JSONAPI::Resource attributes :title, :trash_cost, :printing_ids, :num_printings, :restriction_ids, :in_restriction attributes :format_ids, :card_pool_ids, :snapshot_ids attributes :card_cycle_ids, :card_set_ids, :attribution + attributes :released_by, :printings_released_by, :designed_by # Synthesized attributes attributes :card_abilities, :images, :latest_printing_id, :restrictions @@ -59,7 +60,7 @@ def restrictions # Printing direct attribute filters filters :card_id, :card_cycle_id, :card_set_id, :display_illustrators, :position, :position_in_set - filters :quantity, :date_release + filters :quantity, :date_release, :designed_by, :released_by # Card attribute filters filters :title, :card_type_id, :side_id, :faction_id, :advancement_requirement From 0f7231d261ea935aac2367f0792e7ea90d4c9c62 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Tue, 17 Oct 2023 20:31:49 -0500 Subject: [PATCH 7/7] Format view migrations. --- .../20231017100710_update_unified_printings_to_version_5.rb | 1 - db/migrate/20231017101245_update_unified_cards_to_version_4.rb | 1 - 2 files changed, 2 deletions(-) diff --git a/db/migrate/20231017100710_update_unified_printings_to_version_5.rb b/db/migrate/20231017100710_update_unified_printings_to_version_5.rb index 6ad8b1a5..7aa72961 100644 --- a/db/migrate/20231017100710_update_unified_printings_to_version_5.rb +++ b/db/migrate/20231017100710_update_unified_printings_to_version_5.rb @@ -1,6 +1,5 @@ class UpdateUnifiedPrintingsToVersion5 < ActiveRecord::Migration[7.0] def change - update_view :unified_printings, version: 5, revert_to_version: 4, diff --git a/db/migrate/20231017101245_update_unified_cards_to_version_4.rb b/db/migrate/20231017101245_update_unified_cards_to_version_4.rb index 7bb88078..aa04cb7c 100644 --- a/db/migrate/20231017101245_update_unified_cards_to_version_4.rb +++ b/db/migrate/20231017101245_update_unified_cards_to_version_4.rb @@ -1,6 +1,5 @@ class UpdateUnifiedCardsToVersion4 < ActiveRecord::Migration[7.0] def change - update_view :unified_cards, version: 4, revert_to_version: 3,