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 AS id, v.sim, cards.imsi, cards.iccid, v.order_id AS order_id, COALESCE (n.company_id, v.company_id) AS company_id, c.name AS company_name, COALESCE (n.package_id, v.package_id) AS package_id, p.name AS package_name, p.sn AS package_sn, p.carrier_operator, p.flows, 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 AS created_at, m.updated_at AS updated_at FROM v LEFT JOIN ( SELECT 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 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) 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