Created
          June 23, 2016 20:32 
        
      - 
      
- 
        Save spencerroan/bd8171c386bc50dfca9405ed7ee3fac3 to your computer and use it in GitHub Desktop. 
  
    
      This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
      Learn more about bidirectional Unicode characters
    
  
  
    
  | with hydrated_activities as ( | |
| select t.user_id, t.intensity, t.occurred_on, u.company_id, u.gender | |
| from simple_activities t inner join users u on u.id = t.user_id | |
| ), | |
| filtered_activities as ( | |
| select * from hydrated_activities where company_id = 12 or company_id = 4 | |
| ), | |
| weekly_activities as ( | |
| select user_id user_id, date_trunc('week', occurred_on) occurred_on, avg(intensity) intensity | |
| from filtered_activities | |
| group by user_id, 2 | |
| order by 2, 1 | |
| ), | |
| activity_counts as ( | |
| select | |
| occurred_on, | |
| sum(case when intensity <= 1.5 then 1 else 0 end) light, | |
| sum(case when intensity > 1.5 and intensity <= 2.5 then 1 else 0 end) moderate, | |
| sum(case when intensity > 2.5 then 1 else 0 end) intense, | |
| (select count(*) from users where company_id = 4 or company_id = 12 and verified_at is not null | |
| and deleted_at is null) total | |
| from weekly_activities | |
| group by occurred_on | |
| order by occurred_on | |
| ) | |
| select | |
| occurred_on, | |
| round((100 * light::float/total)::numeric, 2) light, | |
| round((100 * moderate::float/total)::numeric, 2) moderate, | |
| round((100 * intense::float/total)::numeric, 2) intense, | |
| light light_count, | |
| moderate moderate_count, | |
| intense intense_count, | |
| total total_count | |
| from activity_counts | |
| ; | 
  
    Sign up for free
    to join this conversation on GitHub.
    Already have an account?
    Sign in to comment