diff --git a/services/service-core-db/migrations/2022-03-03-170058_remove_status_deleted_to_subscriptions_view/down.sql b/services/service-core-db/migrations/2022-03-03-170058_remove_status_deleted_to_subscriptions_view/down.sql new file mode 100644 index 0000000000..08e121606f --- /dev/null +++ b/services/service-core-db/migrations/2022-03-03-170058_remove_status_deleted_to_subscriptions_view/down.sql @@ -0,0 +1,159 @@ +CREATE OR REPLACE VIEW "payment_service_api"."subscriptions" AS +SELECT s.id, + s.project_id, + CASE + WHEN core.is_owner_or_admin(s.user_id) THEN s.credit_card_id + ELSE NULL::uuid + END AS credit_card_id, + CASE + WHEN (core.is_owner_or_admin(p.user_id) OR core.is_owner_or_admin(s.user_id)) THEN stats.paid_count + ELSE NULL::bigint + END AS paid_count, + CASE + WHEN (core.is_owner_or_admin(p.user_id) OR core.is_owner_or_admin(s.user_id)) THEN stats.total_paid + ELSE (NULL::bigint)::numeric + END AS total_paid, + s.status, + payment_service.paid_transition_at(ROW(last_paid_payment.id, last_paid_payment.platform_id, last_paid_payment.project_id, last_paid_payment.user_id, last_paid_payment.subscription_id, last_paid_payment.reward_id, last_paid_payment.data, last_paid_payment.gateway, last_paid_payment.gateway_cached_data, last_paid_payment.created_at, last_paid_payment.updated_at, last_paid_payment.common_contract_data, last_paid_payment.gateway_general_data, last_paid_payment.status, last_paid_payment.external_id, last_paid_payment.error_retry_at, NULL::uuid)) AS paid_at, + (last_paid_payment.created_at + (core.get_setting('subscription_interval'::character varying))::interval) AS next_charge_at, + CASE + WHEN core.is_owner_or_admin(s.user_id) THEN ((((s.checkout_data - 'card_id'::text) - 'card_hash'::text) - 'current_ip'::text) || jsonb_build_object('customer', (((s.checkout_data ->> 'customer'::text))::jsonb || jsonb_build_object('name', (u.data ->> 'name'::text), 'email', (u.data ->> 'email'::text), 'document_number', (u.data ->> 'document_number'::text))))) + ELSE NULL::jsonb + END AS checkout_data, + s.created_at, + s.user_id, + s.reward_id, + ((last_payment.data ->> 'amount'::text))::numeric AS amount, + p.external_id AS project_external_id, + r.external_id AS reward_external_id, + u.external_id AS user_external_id, + COALESCE((s.checkout_data ->> 'payment_method'::text), (last_payment.data ->> 'payment_method'::text)) AS payment_method, + last_payment.id AS last_payment_id, + last_paid_payment.id AS last_paid_payment_id, + last_paid_payment.created_at AS last_paid_payment_created_at, + (u.data ->> 'email'::text) AS user_email, + s.search_index, + current_paid_subscription.data AS current_paid_subscription, + + -- Select from rewards, the last paid reward, but if it has no payment, load from subscription data + case when stats.paid_count = 0 + then subscription_reward.data + else current_paid_subscription.current_reward_data + end as current_reward_data, + + -- Select from rewards, the last paid reward, but if it has no payment, load from subscription data + case when stats.paid_count = 0 + then s.reward_id + else current_paid_subscription.current_reward_id + end as current_reward_id, + + -- Select from rewards, the last paid reward, but if it has no payment, load from subscription data + case when stats.paid_count = 0 + then subscription_reward.external_id + else current_paid_subscription.current_reward_external_id + end as current_reward_external_id, + + + json_build_object('id', last_payment.id, 'status', last_payment.status, 'created_at', last_payment.created_at, 'payment_method', (last_payment.data ->> 'payment_method'::text), 'refused_at', + CASE + WHEN (last_payment.status = 'refused'::payment_service.payment_status) THEN payment_service.refused_transition_at(ROW(last_payment.id, last_payment.platform_id, last_payment.project_id, last_payment.user_id, last_payment.subscription_id, last_payment.reward_id, last_payment.data, last_payment.gateway, last_payment.gateway_cached_data, last_payment.created_at, last_payment.updated_at, last_payment.common_contract_data, last_payment.gateway_general_data, last_payment.status, last_payment.external_id, last_payment.error_retry_at, NULL::uuid)) + ELSE NULL::timestamp without time zone + END, 'next_retry_at', + CASE + WHEN (((last_payment.data ->> 'payment_method'::text) = 'credit_card'::text) AND (last_payment.status = 'refused'::payment_service.payment_status)) THEN (payment_service.refused_transition_at(ROW(last_payment.id, last_payment.platform_id, last_payment.project_id, last_payment.user_id, last_payment.subscription_id, last_payment.reward_id, last_payment.data, last_payment.gateway, last_payment.gateway_cached_data, last_payment.created_at, last_payment.updated_at, last_payment.common_contract_data, last_payment.gateway_general_data, last_payment.status, last_payment.external_id, last_payment.error_retry_at, NULL::uuid)) + '4 days'::interval) + WHEN (((last_payment.data ->> 'payment_method'::text) = 'boleto'::text) AND (last_payment.status = 'refused'::payment_service.payment_status)) THEN (payment_service.refused_transition_at(ROW(last_payment.id, last_payment.platform_id, last_payment.project_id, last_payment.user_id, last_payment.subscription_id, last_payment.reward_id, last_payment.data, last_payment.gateway, last_payment.gateway_cached_data, last_payment.created_at, last_payment.updated_at, last_payment.common_contract_data, last_payment.gateway_general_data, last_payment.status, last_payment.external_id, last_payment.error_retry_at, NULL::uuid)) + '3 days'::interval) + ELSE NULL::timestamp without time zone + END) AS last_payment_data, + json_build_object('id', last_paid_payment.id, 'status', last_paid_payment.status, 'created_at', last_paid_payment.created_at, 'payment_method', (last_payment.data ->> 'payment_method'::text)) AS last_paid_payment_data, + last_payment.created_at AS last_payment_data_created_at, + ((s.checkout_data ->> 'anonymous'::text) = 'true'::text) AS anonymous, + subscriptions_project_data.project_name +FROM payment_service.subscriptions s + JOIN project_service.projects p ON p.id = s.project_id + JOIN community_service.users u ON u.id = s.user_id + LEFT JOIN project_service.rewards r ON r.id = s.reward_id + LEFT JOIN LATERAL ( + SELECT + sum(((cp.data ->> 'amount'::text))::numeric) FILTER (WHERE (cp.status = 'paid'::payment_service.payment_status)) AS total_paid, + count(1) FILTER (WHERE (cp.status = 'paid'::payment_service.payment_status)) AS paid_count, + count(1) FILTER (WHERE (cp.status = 'refused'::payment_service.payment_status)) AS refused_count + FROM payment_service.catalog_payments cp + WHERE (cp.subscription_id = s.id) + LIMIT 1 + ) stats ON true + LEFT JOIN LATERAL payment_service.get_last_paid_payment(s.id) + last_paid_payment( + id, + platform_id, + project_id, + user_id, + subscription_id, + reward_id, + data, + gateway, + gateway_cached_data, + created_at, + updated_at, + common_contract_data, + gateway_general_data, + status, + external_id, + error_retry_at, + contribution_id + ) ON true + LEFT JOIN LATERAL ( + SELECT cp.id, + cp.platform_id, + cp.project_id, + cp.user_id, + cp.subscription_id, + cp.reward_id, + cp.data, + cp.gateway, + cp.gateway_cached_data, + cp.created_at, + cp.updated_at, + cp.common_contract_data, + cp.gateway_general_data, + cp.status, + cp.external_id, + cp.error_retry_at + FROM payment_service.catalog_payments cp + WHERE cp.subscription_id = s.id + ORDER BY cp.created_at DESC + LIMIT 1 + ) last_payment ON true + LEFT JOIN LATERAL ( + SELECT cp_version_check.subscription_id, + cp_version_check.data, + cp_version_check.created_at, + cp_version_check.updated_at, + COALESCE(current_reward_data.data, '{}'::jsonb) AS current_reward_data, + COALESCE(current_reward_data.id, NULL::uuid) AS current_reward_id, + COALESCE(current_reward_data.external_id, NULL::text) AS current_reward_external_id + FROM payment_service.catalog_payments cp_version_check + LEFT JOIN project_service.rewards current_reward_data ON current_reward_data.id = cp_version_check.reward_id + WHERE ( + (cp_version_check.platform_id = s.platform_id) AND + (cp_version_check.project_id = s.project_id) AND + (cp_version_check.subscription_id = s.id) AND + (cp_version_check.user_id = s.user_id) AND + (cp_version_check.status = 'paid'::payment_service.payment_status) + ) + ORDER BY cp_version_check.created_at DESC + LIMIT 1 + ) current_paid_subscription ON true + LEFT JOIN LATERAL ( + SELECT project.name AS project_name + FROM project_service.projects project + WHERE s.project_id = project.id + LIMIT 1 + ) subscriptions_project_data ON true + LEFT JOIN LATERAL ( + SELECT * FROM project_service.rewards reward WHERE s.reward_id = reward.id LIMIT 1 + ) subscription_reward ON true +WHERE ( + (s.status <> 'deleted'::payment_service.subscription_status) AND + (s.platform_id = core.current_platform_id()) AND + (core.is_owner_or_admin(s.user_id) OR core.is_owner_or_admin(p.user_id)) +); diff --git a/services/service-core-db/migrations/2022-03-03-170058_remove_status_deleted_to_subscriptions_view/up.sql b/services/service-core-db/migrations/2022-03-03-170058_remove_status_deleted_to_subscriptions_view/up.sql new file mode 100644 index 0000000000..285dce46c4 --- /dev/null +++ b/services/service-core-db/migrations/2022-03-03-170058_remove_status_deleted_to_subscriptions_view/up.sql @@ -0,0 +1,119 @@ +CREATE OR REPLACE VIEW "payment_service_api"."subscriptions" AS + SELECT s.id, + s.project_id, + CASE + WHEN core.is_owner_or_admin(s.user_id) THEN s.credit_card_id + ELSE NULL::uuid + END AS credit_card_id, + CASE + WHEN (core.is_owner_or_admin(p.user_id) OR core.is_owner_or_admin(s.user_id)) THEN stats.paid_count + ELSE NULL::bigint + END AS paid_count, + CASE + WHEN (core.is_owner_or_admin(p.user_id) OR core.is_owner_or_admin(s.user_id)) THEN stats.total_paid + ELSE (NULL::bigint)::numeric + END AS total_paid, + s.status, + payment_service.paid_transition_at(ROW(last_paid_payment.id, last_paid_payment.platform_id, last_paid_payment.project_id, last_paid_payment.user_id, last_paid_payment.subscription_id, last_paid_payment.reward_id, last_paid_payment.data, last_paid_payment.gateway, last_paid_payment.gateway_cached_data, last_paid_payment.created_at, last_paid_payment.updated_at, last_paid_payment.common_contract_data, last_paid_payment.gateway_general_data, last_paid_payment.status, last_paid_payment.external_id, last_paid_payment.error_retry_at, NULL::uuid)) AS paid_at, + (last_paid_payment.created_at + (core.get_setting('subscription_interval'::character varying))::interval) AS next_charge_at, + CASE + WHEN core.is_owner_or_admin(s.user_id) THEN ((((s.checkout_data - 'card_id'::text) - 'card_hash'::text) - 'current_ip'::text) || jsonb_build_object('customer', (((s.checkout_data ->> 'customer'::text))::jsonb || jsonb_build_object('name', (u.data ->> 'name'::text), 'email', (u.data ->> 'email'::text), 'document_number', (u.data ->> 'document_number'::text))))) + ELSE NULL::jsonb + END AS checkout_data, + s.created_at, + s.user_id, + s.reward_id, + ((last_payment.data ->> 'amount'::text))::numeric AS amount, + p.external_id AS project_external_id, + r.external_id AS reward_external_id, + u.external_id AS user_external_id, + COALESCE((s.checkout_data ->> 'payment_method'::text), (last_payment.data ->> 'payment_method'::text)) AS payment_method, + last_payment.id AS last_payment_id, + last_paid_payment.id AS last_paid_payment_id, + last_paid_payment.created_at AS last_paid_payment_created_at, + (u.data ->> 'email'::text) AS user_email, + s.search_index, + current_paid_subscription.data AS current_paid_subscription, + CASE + WHEN (stats.paid_count = 0) THEN subscription_reward.data + ELSE current_paid_subscription.current_reward_data + END AS current_reward_data, + CASE + WHEN (stats.paid_count = 0) THEN s.reward_id + ELSE current_paid_subscription.current_reward_id + END AS current_reward_id, + CASE + WHEN (stats.paid_count = 0) THEN subscription_reward.external_id + ELSE current_paid_subscription.current_reward_external_id + END AS current_reward_external_id, + json_build_object('id', last_payment.id, 'status', last_payment.status, 'created_at', last_payment.created_at, 'payment_method', (last_payment.data ->> 'payment_method'::text), 'refused_at', + CASE + WHEN (last_payment.status = 'refused'::payment_service.payment_status) THEN payment_service.refused_transition_at(ROW(last_payment.id, last_payment.platform_id, last_payment.project_id, last_payment.user_id, last_payment.subscription_id, last_payment.reward_id, last_payment.data, last_payment.gateway, last_payment.gateway_cached_data, last_payment.created_at, last_payment.updated_at, last_payment.common_contract_data, last_payment.gateway_general_data, last_payment.status, last_payment.external_id, last_payment.error_retry_at, NULL::uuid)) + ELSE NULL::timestamp without time zone + END, 'next_retry_at', + CASE + WHEN (((last_payment.data ->> 'payment_method'::text) = 'credit_card'::text) AND (last_payment.status = 'refused'::payment_service.payment_status)) THEN (payment_service.refused_transition_at(ROW(last_payment.id, last_payment.platform_id, last_payment.project_id, last_payment.user_id, last_payment.subscription_id, last_payment.reward_id, last_payment.data, last_payment.gateway, last_payment.gateway_cached_data, last_payment.created_at, last_payment.updated_at, last_payment.common_contract_data, last_payment.gateway_general_data, last_payment.status, last_payment.external_id, last_payment.error_retry_at, NULL::uuid)) + '4 days'::interval) + WHEN (((last_payment.data ->> 'payment_method'::text) = 'boleto'::text) AND (last_payment.status = 'refused'::payment_service.payment_status)) THEN (payment_service.refused_transition_at(ROW(last_payment.id, last_payment.platform_id, last_payment.project_id, last_payment.user_id, last_payment.subscription_id, last_payment.reward_id, last_payment.data, last_payment.gateway, last_payment.gateway_cached_data, last_payment.created_at, last_payment.updated_at, last_payment.common_contract_data, last_payment.gateway_general_data, last_payment.status, last_payment.external_id, last_payment.error_retry_at, NULL::uuid)) + '3 days'::interval) + ELSE NULL::timestamp without time zone + END) AS last_payment_data, + json_build_object('id', last_paid_payment.id, 'status', last_paid_payment.status, 'created_at', last_paid_payment.created_at, 'payment_method', (last_payment.data ->> 'payment_method'::text)) AS last_paid_payment_data, + last_payment.created_at AS last_payment_data_created_at, + ((s.checkout_data ->> 'anonymous'::text) = 'true'::text) AS anonymous, + subscriptions_project_data.project_name + FROM (((((((((payment_service.subscriptions s + JOIN project_service.projects p ON ((p.id = s.project_id))) + JOIN community_service.users u ON ((u.id = s.user_id))) + LEFT JOIN project_service.rewards r ON ((r.id = s.reward_id))) + LEFT JOIN LATERAL ( SELECT sum(((cp.data ->> 'amount'::text))::numeric) FILTER (WHERE (cp.status = 'paid'::payment_service.payment_status)) AS total_paid, + count(1) FILTER (WHERE (cp.status = 'paid'::payment_service.payment_status)) AS paid_count, + count(1) FILTER (WHERE (cp.status = 'refused'::payment_service.payment_status)) AS refused_count + FROM payment_service.catalog_payments cp + WHERE (cp.subscription_id = s.id) + LIMIT 1) stats ON (true)) + LEFT JOIN LATERAL payment_service.get_last_paid_payment(s.id) last_paid_payment(id, platform_id, project_id, user_id, subscription_id, reward_id, data, gateway, gateway_cached_data, created_at, updated_at, common_contract_data, gateway_general_data, status, external_id, error_retry_at, contribution_id) ON (true)) + LEFT JOIN LATERAL ( SELECT cp.id, + cp.platform_id, + cp.project_id, + cp.user_id, + cp.subscription_id, + cp.reward_id, + cp.data, + cp.gateway, + cp.gateway_cached_data, + cp.created_at, + cp.updated_at, + cp.common_contract_data, + cp.gateway_general_data, + cp.status, + cp.external_id, + cp.error_retry_at + FROM payment_service.catalog_payments cp + WHERE (cp.subscription_id = s.id) and (cp.status <> 'deleted'::payment_service.payment_status) -- adicionado <> deleted + ORDER BY cp.created_at DESC + LIMIT 1) last_payment ON (true)) + LEFT JOIN LATERAL ( SELECT cp_version_check.subscription_id, + cp_version_check.data, + cp_version_check.created_at, + cp_version_check.updated_at, + COALESCE(current_reward_data.data, '{}'::jsonb) AS current_reward_data, + COALESCE(current_reward_data.id, NULL::uuid) AS current_reward_id, + COALESCE(current_reward_data.external_id, NULL::text) AS current_reward_external_id + FROM (payment_service.catalog_payments cp_version_check + LEFT JOIN project_service.rewards current_reward_data ON ((current_reward_data.id = cp_version_check.reward_id))) + WHERE ((cp_version_check.platform_id = s.platform_id) AND (cp_version_check.project_id = s.project_id) AND (cp_version_check.subscription_id = s.id) AND (cp_version_check.user_id = s.user_id) AND (cp_version_check.status = 'paid'::payment_service.payment_status)) + ORDER BY cp_version_check.created_at DESC + LIMIT 1) current_paid_subscription ON (true)) + LEFT JOIN LATERAL ( SELECT project.name AS project_name + FROM project_service.projects project + WHERE (s.project_id = project.id) + LIMIT 1) subscriptions_project_data ON (true)) + LEFT JOIN LATERAL ( SELECT reward.id, + reward.project_id, + reward.data, + reward.created_at, + reward.updated_at, + reward.external_id + FROM project_service.rewards reward + WHERE (s.reward_id = reward.id) + LIMIT 1) subscription_reward ON (true)) + WHERE ((s.status <> 'deleted'::payment_service.subscription_status) AND (s.platform_id = core.current_platform_id()) AND (core.is_owner_or_admin(s.user_id) OR core.is_owner_or_admin(p.user_id)));