festinko

Untitled

Nov 7th, 2022
69
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
MySQL 8.76 KB | None | 0 0
  1. WITH
  2.  
  3. /*List of all successful subscription payments - Alltime*/
  4.     SuccessSubsPayment AS(
  5.          SELECT
  6.             userID,
  7.             paymentDateTime,
  8.             paymentPeriod,
  9.             productID
  10.  
  11.          FROM `uptimerobot-001.ur.payments`
  12.          WHERE
  13.           paymentType = 2
  14.           AND paymentStatus = 1
  15.      ),
  16.  
  17. /*Last successful subscription payments by user*/
  18.      LastSuccessSubsPayment AS(
  19.          SELECT
  20.             p1.userID,
  21.             p1.paymentDateTime as lastPaymentDateTime,
  22.             p1.paymentPeriod as lastPaymentPeriod,
  23.             p1.productID as lastPaymentProductID
  24.  
  25.         FROM SuccessSubsPayment p1
  26.         LEFT JOIN SuccessSubsPayment p2
  27.         ON (p1.userID = p2.userID AND p1.paymentDateTime < p2.paymentDateTime)
  28.         WHERE
  29.             p2.userID IS NULL
  30.  
  31.      ),
  32.  
  33. /*added userType - Current / Churned Customer*/
  34.     LastSubsPaymentUsersType AS (
  35.             SELECT
  36.                 userID,
  37.                 lastPaymentDateTime,
  38.                 lastPaymentPeriod,
  39.                 (CASE
  40.                     WHEN (DATE_ADD(DATETIME(lastPaymentDateTime), INTERVAL lastPaymentPeriod MONTH) >= CURRENT_DATE()) THEN 'CurrentCustomer'
  41.                     ELSE 'ChurnedCustomer'
  42.                 END) AS customerType,
  43.                 lastPaymentProductID
  44.             FROM LastSuccessSubsPayment
  45.     ),
  46.  
  47. /*added productName & ProductValue*/
  48.     LastSubsPaymentUsersTypeProduct AS (
  49.             SELECT
  50.                 lsput.userID,
  51.                 lsput.lastPaymentDateTime,
  52.                 lsput.lastPaymentPeriod,
  53.                 lsput.customerType,
  54.                 lsput.lastPaymentProductID,
  55.                 pr.productName,
  56.                 pr.productValue
  57.  
  58.             FROM
  59.                 LastSubsPaymentUsersType as lsput
  60.             LEFT JOIN `uptimerobot-001.ur.products` as pr
  61.                 ON pr.productID = lsput.lastPaymentProductID
  62.     ),
  63.  
  64. /*Deduplication of multiple last successful payments from the same user - some edge cases*/
  65.  LastSuccessSubsPaymentUserTypeProduct AS (
  66.     SELECT
  67.         userID,
  68.         MAX(lastPaymentDateTime) as lastPaymentDateTime,
  69.         MAX(lastPaymentPeriod) as lastPaymentPeriod,
  70.         MAX(customerType) as customerType,
  71.         MAX(lastPaymentProductID) as lastPaymentProductID,
  72.         MAX(productName) as lastPaymentProductName,
  73.         MAX(productValue) as lastPaymentProductValue
  74.  
  75.     FROM LastSubsPaymentUsersTypeProduct
  76.  
  77.     GROUP BY userID
  78.     ORDER BY userID DESC
  79.     ),
  80.  
  81. /*List of All Active Team Integration Alert Contacts*/
  82.    TeamIntegrationAlertContacts AS (
  83.  
  84.         SELECT
  85.             userID,
  86.             alertContactType,
  87.             alertContactValue,
  88.             alertContactStatus
  89.         FROM `uptimerobot-001.ur.alertcontacts`
  90.         WHERE alertContactType IN (5,7,11,15,17,18,20) AND alertContactStatus = 2
  91.         ),
  92.    
  93.   /*List users with number of unique team integrations alertContacts*/
  94.     countOfTeamIntegrationAlertContactsByUser AS (
  95.       SELECT
  96.         userID,
  97.         COUNT(DISTINCT alertContactValue) as uniqueTeamIntegrationsCount
  98.       FROM
  99.         TeamIntegrationAlertContacts
  100.      
  101.       GROUP BY
  102.         userID
  103.     ),
  104.    
  105. /*List of All Active Not Default E-mail Alert Contacts*/
  106.     NotDefaultEmailAlertContacts AS (
  107.  
  108.         SELECT
  109.             userID,
  110.             alertContactType,
  111.             alertContactValue,
  112.             alertContactStatus,
  113.             rand() as random
  114.         FROM `uptimerobot-001.ur.alertcontacts`
  115.         WHERE
  116.           alertContactType = 2
  117.           AND alertContactStatus = 2
  118.         ),
  119.  
  120. /*Number of Active Unique E-mail Alert Contacts per user*/
  121.     CountOfUniqueEmailAlertContactsPerUser AS(
  122.         SELECT
  123.             userID,
  124.             count(DISTINCT alertContactValue) uniqueEmailAlertContacts
  125.         FROM NotDefaultEmailAlertContacts
  126.         GROUP BY userID
  127.         ORDER BY uniqueEmailAlertContacts DESC
  128.  
  129.     ),
  130.  
  131. /*List of all users with the count of active unique not default Email Alert Contacts by user type - FREE / Current / Churned Customer & productName & productValue*/
  132. EmailAlertContacts AS(
  133.     SELECT
  134.         CountOfUniqueEmailAlertContactsPerUser.userID,
  135.         uniqueEmailAlertContacts,
  136.         (CASE
  137.             WHEN customerType IS NULL THEN 'FREE'
  138.             ELSE customerType
  139.         END) as customerType,
  140.         (CASE
  141.             WHEN lastPaymentProductName IS NULL THEN 'FREE'
  142.             ELSE lastPaymentProductName
  143.         END) as lastPaymentProductName,
  144.         (CASE
  145.             WHEN lastPaymentProductValue IS NULL THEN 0
  146.             ELSE lastPaymentProductValue
  147.         END) as lastPaymentProductValue
  148.        
  149.  
  150.     FROM CountOfUniqueEmailAlertContactsPerUser
  151.     LEFT JOIN LastSuccessSubsPaymentUserTypeProduct
  152.         on CountOfUniqueEmailAlertContactsPerUser.userID = LastSuccessSubsPaymentUserTypeProduct.userID
  153.     ),
  154. /*Number of Users with active Not Default Email AlertContact by customer type and lastPaymentProduct*/
  155. /*
  156. SELECT
  157.     customerType,
  158.     lastPaymentProductName,
  159.     count(userID) as userCount
  160. FROM EmailAlertContacts
  161. GROUP BY
  162.     customerType,
  163.     lastPaymentProductName,
  164.     lastPaymentProductValue
  165. ORDER BY
  166.     customerType,
  167.     lastPaymentProductValue*/
  168.  
  169. preFinalData as (
  170.  
  171.   SELECT
  172.         NotDefaultEmailAlertContacts.userID,
  173.         userEmail,
  174.         MD5(CAST(NotDefaultEmailAlertContacts.userID as string)) hashedUserID,
  175.         DENSE_RANK() OVER (PARTITION BY customerType ORDER BY MD5(CAST(NotDefaultEmailAlertContacts.userID as string))) as rank,
  176.         (CASE
  177.             WHEN
  178.                 userEmail IS NULL THEN '_onlyDefaultEmailAlertContact'
  179.                 ELSE userEmail
  180.             END) userEmailDefault,
  181.         alertContactType,
  182.         alertContactValue,
  183.         (CASE
  184.             WHEN alertContactValue = userEmail THEN 1
  185.             WHEN alertContactValue <> userEmail THEN 0
  186.         ELSE 999999999
  187.         END
  188.         ) isDefaultAlertContact,
  189.         (CASE
  190.             WHEN alertContactValue = userEmail THEN uniqueEmailAlertContacts - 1
  191.             WHEN alertContactValue <> userEmail THEN uniqueEmailAlertContacts
  192.         ELSE 999999999
  193.         END
  194.         ) uniqueEmailAlertContactsCorrected,
  195.         alertContactStatus,
  196.         uniqueEmailAlertContacts,
  197.         (CASE
  198.             WHEN alertContactValue = userEmail AND uniqueEmailAlertContacts <= 4 THEN '<=3'
  199.             WHEN alertContactValue = userEmail AND uniqueEmailAlertContacts >= 5 AND uniqueEmailAlertContacts <= 7 THEN '<4 - 6>'
  200.             WHEN alertContactValue = userEmail AND uniqueEmailAlertContacts >= 8 AND uniqueEmailAlertContacts <= 12 THEN '<7 - 11>'
  201.             WHEN alertContactValue = userEmail AND uniqueEmailAlertContacts >= 13 THEN '>=12'
  202.            
  203.  
  204.             WHEN alertContactValue <> userEmail AND uniqueEmailAlertContacts <= 3 THEN '<=3'
  205.             WHEN alertContactValue <> userEmail AND uniqueEmailAlertContacts >= 4 AND uniqueEmailAlertContacts <= 6 THEN '<4 - 6>'
  206.             WHEN alertContactValue <> userEmail AND uniqueEmailAlertContacts >= 7 AND uniqueEmailAlertContacts <= 11 THEN '<7 - 11>'
  207.             WHEN alertContactValue <> userEmail AND uniqueEmailAlertContacts >= 12 THEN '>=12'
  208.  
  209.             ELSE 'WTF'
  210.         END) emailAlertContactsBucket,
  211.         (CASE
  212.             WHEN customerType IS NULL THEN 'FREE'
  213.             ELSE customerType
  214.         END) as customerType,
  215.         (CASE
  216.             WHEN lastPaymentProductName IS NULL THEN 'FREE'
  217.             ELSE lastPaymentProductName
  218.         END) as lastPaymentProductName,
  219.         (CASE
  220.             WHEN lastPaymentProductValue IS NULL THEN 0
  221.             ELSE lastPaymentProductValue
  222.         END) as lastPaymentProductValue,
  223.         (CASE
  224.             WHEN uniqueTeamIntegrationsCount IS NULL THEN 0
  225.             ELSE uniqueTeamIntegrationsCount
  226.         END) uniqueTeamIntegrationsCount
  227.        
  228.  
  229.     FROM
  230.         NotDefaultEmailAlertContacts
  231.  
  232.     LEFT JOIN
  233.         CountOfUniqueEmailAlertContactsPerUser
  234.     ON NotDefaultEmailAlertContacts.userID = CountOfUniqueEmailAlertContactsPerUser.userID
  235.    
  236.     LEFT JOIN
  237.         `uptimerobot-001.ur.users` u
  238.     ON NotDefaultEmailAlertContacts.userID = u.userID
  239.    
  240.     LEFT JOIN LastSuccessSubsPaymentUserTypeProduct
  241.     ON NotDefaultEmailAlertContacts.userID = LastSuccessSubsPaymentUserTypeProduct.userID
  242.  
  243.     LEFT JOIN countOfTeamIntegrationAlertContactsByUser
  244.     ON NotDefaultEmailAlertContacts.userID = countOfTeamIntegrationAlertContactsByUser.userID
  245.  
  246.    
  247.     WHERE NotDefaultEmailAlertContacts.userID IS NOT NULL
  248.  
  249.     ORDER BY
  250.         customerType DESC,
  251.         hashedUserID,
  252.         emailAlertContactsBucket,
  253.         userID DESC)
  254.  
  255. SELECT
  256.   *
  257.  
  258. FROM
  259.   preFinalData
  260.  
  261. WHERE
  262.   isDefaultAlertContact = 0
  263.  
Add Comment
Please, Sign In to add comment