diff --git a/super-mode-calculator/src/lib/build-query.ts b/super-mode-calculator/src/lib/build-query.ts index 6541999..bf6e531 100644 --- a/super-mode-calculator/src/lib/build-query.ts +++ b/super-mode-calculator/src/lib/build-query.ts @@ -29,83 +29,89 @@ export const buildQueryForSuperMode = ( return ` WITH -acquisitions_with_regions AS (SELECT *,${regionSql('country_Code')} - FROM datatech-platform-${stage.toLowerCase()}.datalake.fact_acquisition_event - WHERE DATE (event_timestamp) >= '${dateString}' AND - event_timestamp >= TIMESTAMP '${dateHourString}' AND event_timestamp < TIMESTAMP '${endDateHourString}'), exchange_rates AS ( - SELECT target, date, (1/rate) AS reverse_rate - FROM datatech-platform-${stage.toLowerCase()}.datalake.fixer_exchange_rates - WHERE date = '${format(dateForCurrencyConversionTable, 'yyyy-MM-dd')}'), -gbp_rate AS ( - SELECT rate, date - FROM datatech-platform-${stage.toLowerCase()}.datalake.fixer_exchange_rates - WHERE target = 'GBP' AND date = '${format( - dateForCurrencyConversionTable, - 'yyyy-MM-dd', - )}'), + SELECT target AS from_currency,(SELECT FIRST_VALUE(rate) OVER (PARTITION BY target ORDER BY rate ASC) AS eur_to_gbp_rate + FROM datatech-platform-prod.datalake.fixer_exchange_rates + WHERE target = 'GBP' AND date = '${format( + dateForCurrencyConversionTable, + 'yyyy-MM-dd', + )}') * (1/rate) AS to_gbp_rate + FROM datatech-platform-prod.datalake.fixer_exchange_rates + WHERE date = '${format(dateForCurrencyConversionTable, 'yyyy-MM-dd')}'), acquisitions AS ( - SELECT - CASE product - WHEN 'SUPPORTER_PLUS' THEN - CASE currency - WHEN 'GBP' THEN - CASE payment_frequency - WHEN 'MONTHLY' THEN 12 - WHEN 'ANNUAL' THEN 120 - END - WHEN 'USD' THEN - CASE payment_frequency - WHEN 'MONTHLY' THEN 15 - WHEN 'ANNUAL' THEN 150 - END - WHEN 'AUD' THEN - CASE payment_frequency - WHEN 'MONTHLY' THEN 20 - WHEN 'ANNUAL' THEN 200 - END - WHEN 'EUR' THEN - CASE payment_frequency - WHEN 'MONTHLY' THEN 12 - WHEN 'ANNUAL' THEN 120 - END - WHEN 'NZD' THEN - CASE payment_frequency - WHEN 'MONTHLY' THEN 20 - WHEN 'ANNUAL' THEN 200 - END - WHEN 'CAD' THEN - CASE payment_frequency - WHEN 'MONTHLY' THEN 15 - WHEN 'ANNUAL' THEN 150 - END - END - WHEN 'CONTRIBUTION' THEN amount - WHEN 'RECURRING_CONTRIBUTION' THEN amount - END - AS amount, product, currency, country_code, referrer_url, payment_frequency, - FROM datatech-platform-${stage.toLowerCase()}.datalake.fact_acquisition_event AS acq - WHERE event_timestamp >= TIMESTAMP '${dateHourString}' AND event_timestamp < TIMESTAMP '${endDateHourString}'), -acquisitions_with_av AS ( - SELECT acq.*, date, CASE payment_frequency - WHEN 'ONE_OFF' THEN amount * exch.reverse_rate - WHEN 'MONTHLY' THEN (amount * exch.reverse_rate)*12 - WHEN 'ANNUAL' THEN amount * exch.reverse_rate - END - AS av_eur, exch.reverse_rate FROM acquisitions AS acq JOIN exchange_rates AS exch ON acq.currency = exch.target), + SELECT + CASE product + WHEN 'SUPPORTER_PLUS' THEN + CASE currency + WHEN 'GBP' THEN + CASE payment_frequency + WHEN 'MONTHLY' THEN 12 + WHEN 'ANNUALLY' THEN 120 + END + WHEN 'USD' THEN + CASE payment_frequency + WHEN 'MONTHLY' THEN 15 + WHEN 'ANNUALLY' THEN 150 + END + WHEN 'AUD' THEN + CASE payment_frequency + WHEN 'MONTHLY' THEN 20 + WHEN 'ANNUAL' THEN 200 + END + WHEN 'EUR' THEN + CASE payment_frequency + WHEN 'MONTHLY' THEN 12 + WHEN 'ANNUALLY' THEN 120 + END + WHEN 'NZD' THEN + CASE payment_frequency + WHEN 'MONTHLY' THEN 20 + WHEN 'ANNUALLY' THEN 200 + END + WHEN 'CAD' THEN + CASE payment_frequency + WHEN 'MONTHLY' THEN 15 + WHEN 'ANNUALLY' THEN 150 + END + END + WHEN 'CONTRIBUTION' THEN amount + WHEN 'RECURRING_CONTRIBUTION' THEN amount + END AS amount, + CASE + WHEN country_Code = 'GB' THEN 'GB' + WHEN country_Code= 'US' THEN 'US' + WHEN country_Code = 'AU' THEN 'AU' + WHEN country_Code = 'NZ' THEN 'NZ' + WHEN country_Code = 'CA' THEN 'CA' + WHEN country_Code IN ( + 'AD', 'AL', 'AT', 'BA', 'BE', 'BG', 'BL', + 'CH', 'CY', 'CZ', 'DE', 'DK', 'EE', 'ES', + 'FI', 'FO', 'FR', 'GF', 'GL', 'GP', 'GR', + 'HR', 'HU', 'IE', 'IT', 'LI', 'LT', 'LU', + 'LV', 'MC', 'ME', 'MF', 'IS', 'MQ', 'MT', + 'NL', 'NO', 'PF', 'PL', 'PM', 'PT', 'RE', + 'RO', 'RS', 'SE', 'SI', 'SJ', 'SK', 'SM', + 'TF', 'TR', 'WF', 'YT', 'VA', 'AX' + ) THEN 'EU' + ELSE + 'ROW' + END AS region, + product, currency, country_code, referrer_url, payment_frequency, + FROM datatech-platform-prod.datalake.fact_acquisition_event AS acq + WHERE event_timestamp >= timestamp '${dateHourString}' AND event_timestamp < timestamp '${endDateHourString}'), acquisitions_with_av_gbp AS ( - SELECT acq_av.*, CASE acq_av.currency - WHEN 'GBP' THEN av_eur ELSE av_eur * (gbp_rate.rate) - END - AS av_gbp FROM acquisitions_with_av AS acq_av JOIN gbp_rate ON acq_av.date = gbp_rate.date), + SELECT acq.*, + CASE payment_frequency + WHEN 'ONE_OFF' THEN amount * exch.to_gbp_rate + WHEN 'MONTHLY' THEN (amount * exch.to_gbp_rate)*12 + WHEN 'ANNUALLY' THEN amount * exch.to_gbp_rate + END AS av_gbp, exch.from_currency + FROM acquisitions AS acq JOIN exchange_rates AS exch ON acq.currency = exch.from_currency), acquisitions_agg AS ( - SELECT country_code, referrer_url, SUM (av_gbp) sum_av_gbp, COUNT (*) acquisitions - FROM acquisitions_with_av_gbp - GROUP BY 1, 2), -av AS ( - SELECT acq_agg.referrer_url AS url, acq_region.region AS region, SUM ( acq_agg.sum_av_gbp) AS total_av, - FROM acquisitions_with_regions as acq_region JOIN acquisitions_agg AS acq_agg ON acq_region.region =acq_agg.country_code - GROUP BY 1, 2), + SELECT region, referrer_url, SUM(av_gbp) sum_av_gbp, COUNT(*) acquisitions + FROM acquisitions_with_av_gbp + GROUP BY 1, 2 + ), views_with_regions AS ( SELECT *, ${regionSql('country_key')} FROM datatech-platform-${stage.toLowerCase()}.online_traffic.fact_page_view_anonymised CROSS JOIN UNNEST(component_event_array) as ce @@ -115,14 +121,14 @@ views AS ( SELECT CONCAT(protocol,'://',host,path) AS url, region, COUNT (*) AS total_views FROM views_with_regions GROUP BY 1, 2) -SELECT av.url, - av.region, - av.total_av AS totalAv, +SELECT acquisitions_agg.referrer_url AS url, + acquisitions_agg.region, + acquisitions_agg.sum_av_gbp AS totalAv, views.total_views AS totalViews, - av.total_av / views.total_views AS avPerView - FROM av - INNER JOIN views ON av.url = views.url AND av.region = views.region + acquisitions_agg.sum_av_gbp / views.total_views AS avPerView + FROM acquisitions_agg + INNER JOIN views ON acquisitions_agg.referrer_url = views.url AND acquisitions_agg.region = views.region WHERE views.total_views > ${SUPER_MODE_MINIMUM_VIEWS} - AND av.total_av > ${SUPER_MODE_MINIMUM_AV} + AND acquisitions_agg.sum_av_gbp > ${SUPER_MODE_MINIMUM_AV} `; };