|
10 | 10 | #
|
11 | 11 | # It's strongly recommended that you check this file into your version control system.
|
12 | 12 |
|
13 |
| -ActiveRecord::Schema[7.0].define(version: 2022_10_26_043658) do |
| 13 | +ActiveRecord::Schema[7.0].define(version: 2022_11_25_065640) do |
14 | 14 | # These are extensions that must be enabled in order to support this database
|
15 | 15 | enable_extension "plpgsql"
|
16 | 16 |
|
|
321 | 321 | add_index "unified_restrictions", ["restriction_id"], name: "index_unified_restrictions_on_restriction_id"
|
322 | 322 | add_index "unified_restrictions", ["snapshot_id"], name: "index_unified_restrictions_on_snapshot_id"
|
323 | 323 |
|
324 |
| - create_view "unified_cards", materialized: true, sql_definition: <<-SQL |
325 |
| - WITH card_cycles_summary AS ( |
326 |
| - SELECT c_1.id, |
327 |
| - array_agg(cc.id ORDER BY cc.id) AS card_cycle_ids, |
328 |
| - array_agg(lower(cc.name) ORDER BY (lower(cc.name))) AS card_cycle_names |
329 |
| - FROM (((cards c_1 |
330 |
| - JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) |
331 |
| - JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) |
332 |
| - JOIN card_cycles cc ON (((cc.id)::text = cs.card_cycle_id))) |
333 |
| - GROUP BY c_1.id |
334 |
| - ), card_sets_summary AS ( |
335 |
| - SELECT c_1.id, |
336 |
| - array_agg(cs.id ORDER BY cs.id) AS card_set_ids, |
337 |
| - array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS card_set_names |
338 |
| - FROM ((cards c_1 |
339 |
| - JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) |
340 |
| - JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) |
341 |
| - GROUP BY c_1.id |
342 |
| - ), card_subtype_ids AS ( |
| 324 | + create_view "unified_printings", materialized: true, sql_definition: <<-SQL |
| 325 | + WITH card_subtype_ids AS ( |
343 | 326 | SELECT cards_card_subtypes.card_id,
|
344 | 327 | array_agg(cards_card_subtypes.card_subtype_id ORDER BY 1::integer) AS card_subtype_ids
|
345 | 328 | FROM cards_card_subtypes
|
346 | 329 | GROUP BY cards_card_subtypes.card_id
|
347 | 330 | ), card_subtype_names AS (
|
348 |
| - SELECT ccs_1.card_id, |
349 |
| - array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS lower_card_subtype_names, |
350 |
| - array_agg(cs.name ORDER BY cs.name) AS card_subtype_names |
351 |
| - FROM (cards_card_subtypes ccs_1 |
352 |
| - JOIN card_subtypes cs ON ((ccs_1.card_subtype_id = (cs.id)::text))) |
353 |
| - GROUP BY ccs_1.card_id |
| 331 | + SELECT ccs.card_id, |
| 332 | + array_agg(lower(cs_1.name) ORDER BY (lower(cs_1.name))) AS lower_card_subtype_names, |
| 333 | + array_agg(cs_1.name ORDER BY cs_1.name) AS card_subtype_names |
| 334 | + FROM (cards_card_subtypes ccs |
| 335 | + JOIN card_subtypes cs_1 ON ((ccs.card_subtype_id = (cs_1.id)::text))) |
| 336 | + GROUP BY ccs.card_id |
354 | 337 | ), card_printing_ids AS (
|
355 | 338 | SELECT printings.card_id,
|
356 | 339 | array_agg(printings.id ORDER BY printings.date_release DESC) AS printing_ids
|
357 | 340 | FROM printings
|
358 | 341 | GROUP BY printings.card_id
|
| 342 | + ), illustrators AS ( |
| 343 | + SELECT ip.printing_id, |
| 344 | + array_agg(ip.illustrator_id ORDER BY ip.illustrator_id) AS illustrator_ids, |
| 345 | + array_agg(i_1.name ORDER BY i_1.name) AS illustrator_names |
| 346 | + FROM (illustrators_printings ip |
| 347 | + JOIN public.illustrators i_1 ON (((ip.illustrator_id)::text = (i_1.id)::text))) |
| 348 | + GROUP BY ip.printing_id |
359 | 349 | ), card_restriction_ids AS (
|
360 | 350 | SELECT unified_restrictions.card_id,
|
361 | 351 | array_agg(unified_restrictions.restriction_id ORDER BY unified_restrictions.restriction_id) AS restriction_ids
|
|
406 | 396 | JOIN snapshots s_1 ON ((cpc_1.card_pool_id = s_1.card_pool_id)))
|
407 | 397 | GROUP BY cpc_1.card_id
|
408 | 398 | )
|
409 |
| - SELECT c.id, |
410 |
| - c.title, |
411 |
| - c.stripped_title, |
412 |
| - c.card_type_id, |
413 |
| - c.side_id, |
414 |
| - c.faction_id, |
| 399 | + SELECT p.id, |
| 400 | + p.card_id, |
| 401 | + cc.id AS card_cycle_id, |
| 402 | + cc.name AS card_cycle_name, |
| 403 | + p.card_set_id, |
| 404 | + cs.name AS card_set_name, |
| 405 | + p.printed_text, |
| 406 | + p.stripped_printed_text, |
| 407 | + p.printed_is_unique, |
| 408 | + p.flavor, |
| 409 | + p.display_illustrators, |
| 410 | + p."position", |
| 411 | + p.quantity, |
| 412 | + p.date_release, |
| 413 | + p.created_at, |
| 414 | + p.updated_at, |
| 415 | + c.additional_cost, |
| 416 | + c.advanceable, |
415 | 417 | c.advancement_requirement,
|
416 | 418 | c.agenda_points,
|
417 | 419 | c.base_link,
|
| 420 | + c.card_type_id, |
418 | 421 | c.cost,
|
419 |
| - c.deck_limit, |
420 |
| - c.influence_cost, |
421 |
| - c.influence_limit, |
422 |
| - c.memory_cost, |
423 |
| - c.minimum_deck_size, |
424 |
| - c.strength, |
425 |
| - c.stripped_text, |
426 |
| - c.text, |
427 |
| - c.trash_cost, |
428 |
| - c.is_unique, |
429 |
| - c.display_subtypes, |
430 |
| - c.attribution, |
431 |
| - c.created_at, |
432 |
| - c.updated_at, |
433 |
| - c.additional_cost, |
434 |
| - c.advanceable, |
| 422 | + c.faction_id, |
435 | 423 | c.gains_subroutines,
|
| 424 | + c.influence_cost, |
436 | 425 | c.interrupt,
|
| 426 | + c.is_unique, |
437 | 427 | c.link_provided,
|
| 428 | + c.memory_cost, |
438 | 429 | c.mu_provided,
|
439 | 430 | c.num_printed_subroutines,
|
440 | 431 | c.on_encounter_effect,
|
441 | 432 | c.performs_trace,
|
442 | 433 | c.recurring_credits_provided,
|
443 |
| - c.rez_effect, |
| 434 | + c.side_id, |
| 435 | + c.strength, |
| 436 | + c.stripped_text, |
| 437 | + c.stripped_title, |
444 | 438 | c.trash_ability,
|
| 439 | + c.trash_cost, |
445 | 440 | COALESCE(csi.card_subtype_ids, ARRAY[]::text[]) AS card_subtype_ids,
|
446 | 441 | COALESCE(csn.lower_card_subtype_names, ARRAY[]::text[]) AS lower_card_subtype_names,
|
447 | 442 | COALESCE(csn.card_subtype_names, ARRAY[]::text[]) AS card_subtype_names,
|
448 |
| - p.printing_ids, |
449 |
| - array_length(p.printing_ids, 1) AS num_printings, |
450 |
| - ccs.card_cycle_ids, |
451 |
| - ccs.card_cycle_names, |
452 |
| - css.card_set_ids, |
453 |
| - css.card_set_names, |
| 443 | + cp.printing_ids, |
| 444 | + array_length(cp.printing_ids, 1) AS num_printings, |
| 445 | + COALESCE(i.illustrator_ids, (ARRAY[]::text[])::character varying[]) AS illustrator_ids, |
| 446 | + COALESCE(i.illustrator_names, (ARRAY[]::text[])::character varying[]) AS illustrator_names, |
454 | 447 | COALESCE(r.restriction_ids, (ARRAY[]::text[])::character varying[]) AS restriction_ids,
|
455 | 448 | (r.restriction_ids IS NOT NULL) AS in_restriction,
|
456 | 449 | COALESCE(r_b.restrictions_banned, ARRAY[]::text[]) AS restrictions_banned,
|
|
460 | 453 | COALESCE(r_u_f_c.restrictions_universal_faction_cost, ARRAY[]::text[]) AS restrictions_universal_faction_cost,
|
461 | 454 | COALESCE(f.format_ids, ARRAY[]::text[]) AS format_ids,
|
462 | 455 | COALESCE(cpc.card_pool_ids, ARRAY[]::text[]) AS card_pool_ids,
|
463 |
| - COALESCE(s.snapshot_ids, (ARRAY[]::text[])::character varying[]) AS snapshot_ids |
464 |
| - FROM ((((((((((((((cards c |
465 |
| - JOIN card_printing_ids p ON (((c.id)::text = p.card_id))) |
466 |
| - JOIN card_cycles_summary ccs ON (((c.id)::text = (ccs.id)::text))) |
467 |
| - JOIN card_sets_summary css ON (((c.id)::text = (css.id)::text))) |
| 456 | + COALESCE(s.snapshot_ids, (ARRAY[]::text[])::character varying[]) AS snapshot_ids, |
| 457 | + c.attribution, |
| 458 | + c.deck_limit, |
| 459 | + c.display_subtypes, |
| 460 | + c.influence_limit, |
| 461 | + c.minimum_deck_size, |
| 462 | + c.rez_effect, |
| 463 | + c.text, |
| 464 | + c.title |
| 465 | + FROM ((((((((((((((((printings p |
| 466 | + JOIN cards c ON ((p.card_id = (c.id)::text))) |
| 467 | + JOIN card_sets cs ON ((p.card_set_id = (cs.id)::text))) |
| 468 | + JOIN card_cycles cc ON ((cs.card_cycle_id = (cc.id)::text))) |
468 | 469 | LEFT JOIN card_subtype_ids csi ON (((c.id)::text = csi.card_id)))
|
469 | 470 | LEFT JOIN card_subtype_names csn ON (((c.id)::text = csn.card_id)))
|
470 |
| - LEFT JOIN card_restriction_ids r ON (((c.id)::text = (r.card_id)::text))) |
471 |
| - LEFT JOIN restrictions_banned_summary r_b ON (((c.id)::text = r_b.card_id))) |
472 |
| - LEFT JOIN restrictions_global_penalty_summary r_g_p ON (((c.id)::text = r_g_p.card_id))) |
473 |
| - LEFT JOIN restrictions_points_summary r_p ON (((c.id)::text = r_p.card_id))) |
474 |
| - LEFT JOIN restrictions_restricted_summary r_r ON (((c.id)::text = r_r.card_id))) |
475 |
| - LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON (((c.id)::text = r_u_f_c.card_id))) |
476 |
| - LEFT JOIN format_ids f ON (((c.id)::text = f.card_id))) |
477 |
| - LEFT JOIN card_pool_ids cpc ON (((c.id)::text = cpc.card_id))) |
478 |
| - LEFT JOIN snapshot_ids s ON (((c.id)::text = s.card_id))) |
479 |
| - 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; |
| 471 | + JOIN card_printing_ids cp ON ((p.card_id = cp.card_id))) |
| 472 | + LEFT JOIN illustrators i ON (((p.id)::text = (i.printing_id)::text))) |
| 473 | + LEFT JOIN card_restriction_ids r ON ((p.card_id = (r.card_id)::text))) |
| 474 | + LEFT JOIN restrictions_banned_summary r_b ON ((p.card_id = r_b.card_id))) |
| 475 | + LEFT JOIN restrictions_global_penalty_summary r_g_p ON ((p.card_id = r_g_p.card_id))) |
| 476 | + LEFT JOIN restrictions_points_summary r_p ON ((p.card_id = r_p.card_id))) |
| 477 | + LEFT JOIN restrictions_restricted_summary r_r ON ((p.card_id = r_r.card_id))) |
| 478 | + LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON ((p.card_id = r_u_f_c.card_id))) |
| 479 | + LEFT JOIN format_ids f ON ((p.card_id = f.card_id))) |
| 480 | + LEFT JOIN card_pool_ids cpc ON ((p.card_id = cpc.card_id))) |
| 481 | + LEFT JOIN snapshot_ids s ON ((p.card_id = s.card_id))); |
480 | 482 | SQL
|
481 |
| - create_view "unified_printings", materialized: true, sql_definition: <<-SQL |
482 |
| - WITH card_subtype_ids AS ( |
| 483 | + create_view "unified_cards", materialized: true, sql_definition: <<-SQL |
| 484 | + WITH card_cycles_summary AS ( |
| 485 | + SELECT c_1.id, |
| 486 | + array_agg(cc.id ORDER BY cc.id) AS card_cycle_ids, |
| 487 | + array_agg(lower(cc.name) ORDER BY (lower(cc.name))) AS card_cycle_names |
| 488 | + FROM (((cards c_1 |
| 489 | + JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) |
| 490 | + JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) |
| 491 | + JOIN card_cycles cc ON (((cc.id)::text = cs.card_cycle_id))) |
| 492 | + GROUP BY c_1.id |
| 493 | + ), card_sets_summary AS ( |
| 494 | + SELECT c_1.id, |
| 495 | + array_agg(cs.id ORDER BY cs.id) AS card_set_ids, |
| 496 | + array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS card_set_names |
| 497 | + FROM ((cards c_1 |
| 498 | + JOIN printings p_1 ON (((c_1.id)::text = p_1.card_id))) |
| 499 | + JOIN card_sets cs ON ((p_1.card_set_id = (cs.id)::text))) |
| 500 | + GROUP BY c_1.id |
| 501 | + ), card_subtype_ids AS ( |
483 | 502 | SELECT cards_card_subtypes.card_id,
|
484 | 503 | array_agg(cards_card_subtypes.card_subtype_id ORDER BY 1::integer) AS card_subtype_ids
|
485 | 504 | FROM cards_card_subtypes
|
486 | 505 | GROUP BY cards_card_subtypes.card_id
|
487 | 506 | ), card_subtype_names AS (
|
488 |
| - SELECT ccs.card_id, |
489 |
| - array_agg(lower(cs_1.name) ORDER BY (lower(cs_1.name))) AS lower_card_subtype_names, |
490 |
| - array_agg(cs_1.name ORDER BY cs_1.name) AS card_subtype_names |
491 |
| - FROM (cards_card_subtypes ccs |
492 |
| - JOIN card_subtypes cs_1 ON ((ccs.card_subtype_id = (cs_1.id)::text))) |
493 |
| - GROUP BY ccs.card_id |
| 507 | + SELECT ccs_1.card_id, |
| 508 | + array_agg(lower(cs.name) ORDER BY (lower(cs.name))) AS lower_card_subtype_names, |
| 509 | + array_agg(cs.name ORDER BY cs.name) AS card_subtype_names |
| 510 | + FROM (cards_card_subtypes ccs_1 |
| 511 | + JOIN card_subtypes cs ON ((ccs_1.card_subtype_id = (cs.id)::text))) |
| 512 | + GROUP BY ccs_1.card_id |
494 | 513 | ), card_printing_ids AS (
|
495 | 514 | SELECT printings.card_id,
|
496 | 515 | array_agg(printings.id ORDER BY printings.date_release DESC) AS printing_ids
|
497 | 516 | FROM printings
|
498 | 517 | GROUP BY printings.card_id
|
499 |
| - ), illustrators AS ( |
500 |
| - SELECT ip.printing_id, |
501 |
| - array_agg(ip.illustrator_id ORDER BY ip.illustrator_id) AS illustrator_ids, |
502 |
| - array_agg(i_1.name ORDER BY i_1.name) AS illustrator_names |
503 |
| - FROM (illustrators_printings ip |
504 |
| - JOIN public.illustrators i_1 ON (((ip.illustrator_id)::text = (i_1.id)::text))) |
505 |
| - GROUP BY ip.printing_id |
| 518 | + ), card_release_dates AS ( |
| 519 | + SELECT printings.card_id, |
| 520 | + min(printings.date_release) AS date_release |
| 521 | + FROM printings |
| 522 | + GROUP BY printings.card_id |
506 | 523 | ), card_restriction_ids AS (
|
507 | 524 | SELECT unified_restrictions.card_id,
|
508 | 525 | array_agg(unified_restrictions.restriction_id ORDER BY unified_restrictions.restriction_id) AS restriction_ids
|
|
553 | 570 | JOIN snapshots s_1 ON ((cpc_1.card_pool_id = s_1.card_pool_id)))
|
554 | 571 | GROUP BY cpc_1.card_id
|
555 | 572 | )
|
556 |
| - SELECT p.id, |
557 |
| - p.card_id, |
558 |
| - cc.id AS card_cycle_id, |
559 |
| - cc.name AS card_cycle_name, |
560 |
| - p.card_set_id, |
561 |
| - cs.name AS card_set_name, |
562 |
| - p.printed_text, |
563 |
| - p.stripped_printed_text, |
564 |
| - p.printed_is_unique, |
565 |
| - p.flavor, |
566 |
| - p.display_illustrators, |
567 |
| - p."position", |
568 |
| - p.quantity, |
569 |
| - p.date_release, |
570 |
| - p.created_at, |
571 |
| - p.updated_at, |
572 |
| - c.additional_cost, |
573 |
| - c.advanceable, |
| 573 | + SELECT c.id, |
| 574 | + c.title, |
| 575 | + c.stripped_title, |
| 576 | + c.card_type_id, |
| 577 | + c.side_id, |
| 578 | + c.faction_id, |
574 | 579 | c.advancement_requirement,
|
575 | 580 | c.agenda_points,
|
576 | 581 | c.base_link,
|
577 |
| - c.card_type_id, |
578 | 582 | c.cost,
|
579 |
| - c.faction_id, |
580 |
| - c.gains_subroutines, |
| 583 | + c.deck_limit, |
581 | 584 | c.influence_cost,
|
582 |
| - c.interrupt, |
| 585 | + c.influence_limit, |
| 586 | + c.memory_cost, |
| 587 | + c.minimum_deck_size, |
| 588 | + c.strength, |
| 589 | + c.stripped_text, |
| 590 | + c.text, |
| 591 | + c.trash_cost, |
583 | 592 | c.is_unique,
|
| 593 | + c.display_subtypes, |
| 594 | + c.attribution, |
| 595 | + c.created_at, |
| 596 | + c.updated_at, |
| 597 | + c.additional_cost, |
| 598 | + c.advanceable, |
| 599 | + c.gains_subroutines, |
| 600 | + c.interrupt, |
584 | 601 | c.link_provided,
|
585 |
| - c.memory_cost, |
586 | 602 | c.mu_provided,
|
587 | 603 | c.num_printed_subroutines,
|
588 | 604 | c.on_encounter_effect,
|
589 | 605 | c.performs_trace,
|
590 | 606 | c.recurring_credits_provided,
|
591 |
| - c.side_id, |
592 |
| - c.strength, |
593 |
| - c.stripped_text, |
594 |
| - c.stripped_title, |
| 607 | + c.rez_effect, |
595 | 608 | c.trash_ability,
|
596 |
| - c.trash_cost, |
597 | 609 | COALESCE(csi.card_subtype_ids, ARRAY[]::text[]) AS card_subtype_ids,
|
598 | 610 | COALESCE(csn.lower_card_subtype_names, ARRAY[]::text[]) AS lower_card_subtype_names,
|
599 | 611 | COALESCE(csn.card_subtype_names, ARRAY[]::text[]) AS card_subtype_names,
|
600 |
| - cp.printing_ids, |
601 |
| - array_length(cp.printing_ids, 1) AS num_printings, |
602 |
| - COALESCE(i.illustrator_ids, (ARRAY[]::text[])::character varying[]) AS illustrator_ids, |
603 |
| - COALESCE(i.illustrator_names, (ARRAY[]::text[])::character varying[]) AS illustrator_names, |
| 612 | + p.printing_ids, |
| 613 | + array_length(p.printing_ids, 1) AS num_printings, |
| 614 | + ccs.card_cycle_ids, |
| 615 | + ccs.card_cycle_names, |
| 616 | + css.card_set_ids, |
| 617 | + css.card_set_names, |
604 | 618 | COALESCE(r.restriction_ids, (ARRAY[]::text[])::character varying[]) AS restriction_ids,
|
605 | 619 | (r.restriction_ids IS NOT NULL) AS in_restriction,
|
606 | 620 | COALESCE(r_b.restrictions_banned, ARRAY[]::text[]) AS restrictions_banned,
|
|
611 | 625 | COALESCE(f.format_ids, ARRAY[]::text[]) AS format_ids,
|
612 | 626 | COALESCE(cpc.card_pool_ids, ARRAY[]::text[]) AS card_pool_ids,
|
613 | 627 | COALESCE(s.snapshot_ids, (ARRAY[]::text[])::character varying[]) AS snapshot_ids,
|
614 |
| - c.attribution, |
615 |
| - c.deck_limit, |
616 |
| - c.display_subtypes, |
617 |
| - c.influence_limit, |
618 |
| - c.minimum_deck_size, |
619 |
| - c.rez_effect, |
620 |
| - c.text, |
621 |
| - c.title |
622 |
| - FROM ((((((((((((((((printings p |
623 |
| - JOIN cards c ON ((p.card_id = (c.id)::text))) |
624 |
| - JOIN card_sets cs ON ((p.card_set_id = (cs.id)::text))) |
625 |
| - JOIN card_cycles cc ON ((cs.card_cycle_id = (cc.id)::text))) |
| 628 | + crd.date_release |
| 629 | + FROM (((((((((((((((cards c |
| 630 | + JOIN card_printing_ids p ON (((c.id)::text = p.card_id))) |
| 631 | + JOIN card_cycles_summary ccs ON (((c.id)::text = (ccs.id)::text))) |
| 632 | + JOIN card_sets_summary css ON (((c.id)::text = (css.id)::text))) |
626 | 633 | LEFT JOIN card_subtype_ids csi ON (((c.id)::text = csi.card_id)))
|
627 | 634 | LEFT JOIN card_subtype_names csn ON (((c.id)::text = csn.card_id)))
|
628 |
| - JOIN card_printing_ids cp ON ((p.card_id = cp.card_id))) |
629 |
| - LEFT JOIN illustrators i ON (((p.id)::text = (i.printing_id)::text))) |
630 |
| - LEFT JOIN card_restriction_ids r ON ((p.card_id = (r.card_id)::text))) |
631 |
| - LEFT JOIN restrictions_banned_summary r_b ON ((p.card_id = r_b.card_id))) |
632 |
| - LEFT JOIN restrictions_global_penalty_summary r_g_p ON ((p.card_id = r_g_p.card_id))) |
633 |
| - LEFT JOIN restrictions_points_summary r_p ON ((p.card_id = r_p.card_id))) |
634 |
| - LEFT JOIN restrictions_restricted_summary r_r ON ((p.card_id = r_r.card_id))) |
635 |
| - LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON ((p.card_id = r_u_f_c.card_id))) |
636 |
| - LEFT JOIN format_ids f ON ((p.card_id = f.card_id))) |
637 |
| - LEFT JOIN card_pool_ids cpc ON ((p.card_id = cpc.card_id))) |
638 |
| - LEFT JOIN snapshot_ids s ON ((p.card_id = s.card_id))); |
| 635 | + LEFT JOIN card_restriction_ids r ON (((c.id)::text = (r.card_id)::text))) |
| 636 | + LEFT JOIN restrictions_banned_summary r_b ON (((c.id)::text = r_b.card_id))) |
| 637 | + LEFT JOIN restrictions_global_penalty_summary r_g_p ON (((c.id)::text = r_g_p.card_id))) |
| 638 | + LEFT JOIN restrictions_points_summary r_p ON (((c.id)::text = r_p.card_id))) |
| 639 | + LEFT JOIN restrictions_restricted_summary r_r ON (((c.id)::text = r_r.card_id))) |
| 640 | + LEFT JOIN restrictions_universal_faction_cost_summary r_u_f_c ON (((c.id)::text = r_u_f_c.card_id))) |
| 641 | + LEFT JOIN format_ids f ON (((c.id)::text = f.card_id))) |
| 642 | + LEFT JOIN card_pool_ids cpc ON (((c.id)::text = cpc.card_id))) |
| 643 | + LEFT JOIN snapshot_ids s ON (((c.id)::text = s.card_id))) |
| 644 | + LEFT JOIN card_release_dates crd ON (((c.id)::text = crd.card_id))) |
| 645 | + 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; |
639 | 646 | SQL
|
640 | 647 | end
|
0 commit comments