diff --git a/database/migrations/create_ckb_order_cards.pgsql b/database/migrations/create_ckb_order_cards.pgsql index d8848316..dd3a1adf 100644 --- a/database/migrations/create_ckb_order_cards.pgsql +++ b/database/migrations/create_ckb_order_cards.pgsql @@ -1,47 +1,59 @@ DROP MATERIALIZED VIEW IF EXISTS ckb_order_cards; CREATE MATERIALIZED VIEW ckb_order_cards AS +WITH v as ( + SELECT DISTINCT ON (sim) + id, + sim, + order_id, + company_id, + package_id, + service_start_at, + created_at + FROM virtual_order_cards_partition + ORDER BY sim,type +) SELECT - v.id, + v.id AS id, v.sim, cards.imsi, cards.iccid, - v.order_id, + v.order_id AS order_id, COALESCE (n.company_id, v.company_id) AS company_id, - c.NAME AS company_name, + c.name AS company_name, COALESCE (n.package_id, v.package_id) AS package_id, - p.NAME AS package_name, + p.name AS package_name, p.sn AS package_sn, p.carrier_operator, p.flows, - t.service_start_at, - t.service_end_at, + v.service_start_at AS service_start_at, + m.service_end_at AS service_end_at, v.created_at AS order_at, - v.created_at, - t.updated_at -FROM - virtual_order_cards_partition v - LEFT JOIN ( - SELECT - virtual_order_cards_partition.sim, - MIN ( virtual_order_cards_partition.service_start_at ) AS service_start_at, - MAX ( virtual_order_cards_partition.service_end_at ) AS service_end_at, - MAX ( virtual_order_cards_partition.updated_at ) AS updated_at - FROM - virtual_order_cards_partition - GROUP BY - virtual_order_cards_partition.sim - ) t ON t.sim = v.sim + v.created_at AS created_at, + m.updated_at AS updated_at +FROM v LEFT JOIN ( SELECT - virtual_order_cards_partition.sim, - virtual_order_cards_partition.company_id, - virtual_order_cards_partition.package_id + sim, + MAX(service_end_at) AS service_end_at, + MAX(updated_at) AS updated_at + FROM + virtual_order_cards_partition + WHERE deleted_at is null AND refunded_at is null + GROUP BY sim + ) m ON m.sim = v.sim + LEFT JOIN ( + SELECT DISTINCT ON (sim) + sim, + company_id, + package_id FROM virtual_order_cards_partition WHERE - virtual_order_cards_partition.service_start_at <= now() AND virtual_order_cards_partition.service_end_at >= now() - ) n ON n.sim = v.sim + service_start_at < now() AND service_end_at >= now() + AND deleted_at is null AND refunded_at is null + ORDER BY sim, service_start_at desc + ) n ON n.sim = v.sim LEFT JOIN cards ON cards.sim = v.sim - LEFT JOIN virtual_packages p ON p.ID = COALESCE (n.package_id, v.package_id) - LEFT JOIN virtual_companies c ON c.id = COALESCE (n.company_id, v.company_id) + LEFT JOIN virtual_packages p ON p.id = COALESCE (n.package_id, v.package_id) AND p.deleted_at is null + LEFT JOIN virtual_companies c ON c.id = COALESCE (n.company_id, v.company_id) AND c.deleted_at is null