Skip to content

Commit b59ab5a

Browse files
authored
Update Challenge 6 -Marketing Analysis.md
1 parent 4441669 commit b59ab5a

File tree

1 file changed

+151
-1
lines changed

1 file changed

+151
-1
lines changed

Challenge 6 -Marketing Analysis.md

Lines changed: 151 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -17,44 +17,194 @@ Here are the tables I created and used in MySQL Workbench 8.0:
1717
```
1818
## Ad-Hoc Questions and Solutions
1919
### 1. How many transactions were completed during each marketing campaign?
20-
```
20+
```sql
21+
SELECT mc.campaign_name,
22+
COUNT(t.transaction_id) as transaction_count
23+
FROM
24+
marketing_campaigns mc
25+
JOIN
26+
transactions2 t ON mc.product_id = t.product_id
27+
GROUP BY
28+
mc.campaign_name;
2129
```
2230

2331
### 2. Which product had the highest sales quantity?
2432

2533
```sql
34+
SELECT
35+
sc.product_name,
36+
SUM(t.quantity) as total_quantity_sold
37+
FROM
38+
sustainable_clothing sc
39+
JOIN
40+
transactions2 t ON sc.product_id = t.product_id
41+
GROUP BY
42+
sc.product_name
43+
ORDER BY
44+
total_quantity_sold DESC
45+
LIMIT 1;
2646
```
2747
### 3. What is the total revenue generated from each marketing campaign?
2848

2949
```sql
50+
SELECT
51+
mc.campaign_name,
52+
ROUND(SUM(t.quantity * sc.price),2) as total_revenue
53+
FROM
54+
marketing_campaigns mc
55+
JOIN
56+
transactions2 t ON mc.product_id = t.product_id
57+
JOIN
58+
sustainable_clothing sc ON mc.product_id = sc.product_id
59+
GROUP BY
60+
mc.campaign_name;
3061
```
3162
### 4. What is the top-selling product category based on the total revenue generated?
3263
```sql
64+
SELECT
65+
sc.category,
66+
ROUND(SUM(t.quantity * sc.price),2) as total_revenue
67+
FROM
68+
sustainable_clothing sc
69+
JOIN
70+
transactions2 t ON sc.product_id = t.product_id
71+
GROUP BY
72+
sc.category
73+
ORDER BY
74+
total_revenue DESC
75+
LIMIT 1;
3376
```
3477
### 5. Which products had a higher quantity sold compared to the average quantity sold?
3578

3679
```sql
80+
SELECT
81+
sc.product_name,
82+
SUM(t.quantity) as total_quantity_sold
83+
FROM
84+
sustainable_clothing sc
85+
JOIN
86+
transactions2 t ON sc.product_id = t.product_id
87+
GROUP BY
88+
sc.product_name
89+
HAVING
90+
total_quantity_sold > (SELECT AVG(quantity) FROM transactions2)
91+
ORDER BY total_quantity_sold DESC;
92+
3793
```
3894
### 6. What is the average revenue generated per day during the marketing campaigns?
3995

4096
```sql
97+
SELECT
98+
mc.campaign_name,
99+
ROUND(AVG(t.quantity * sc.price),2) as average_daily_revenue
100+
FROM
101+
marketing_campaigns mc
102+
JOIN
103+
transactions2 t ON mc.product_id = t.product_id
104+
JOIN
105+
sustainable_clothing sc ON mc.product_id = sc.product_id
106+
GROUP BY
107+
mc.campaign_name
108+
ORDER BY
109+
mc.campaign_name;
41110
```
42111
### 7. What is the percentage contribution of each product to the total revenue?
43112

44113
```sql
114+
WITH product_revenue AS (
115+
SELECT
116+
sc.product_name,
117+
ROUND(SUM(t.quantity * sc.price),2) as total_revenue
118+
FROM
119+
sustainable_clothing sc
120+
JOIN
121+
transactions2 t ON sc.product_id = t.product_id
122+
GROUP BY
123+
sc.product_name
124+
)
125+
SELECT
126+
product_name,
127+
total_revenue,
128+
ROUND((total_revenue / (SELECT SUM(total_revenue) FROM product_revenue)) * 100,2) as percentage_contribution
129+
FROM
130+
product_revenue
131+
ORDER BY
132+
total_revenue DESC;
45133
```
46134
### 8. Compare the average quantity sold during marketing campaigns to outside marketing campaigns.
47135

48136
```sql
137+
WITH campaign_quantity AS (
138+
SELECT mc.campaign_name,
139+
AVG(t.quantity) as average_quantity_sold
140+
FROM
141+
marketing_campaigns mc
142+
JOIN
143+
transactions2 t ON mc.product_id = t.product_id
144+
GROUP BY
145+
mc.campaign_name
146+
),
147+
outside_campaign_quantity AS (
148+
SELECT 'Outside Campaigns' as campaign_name,
149+
AVG(t.quantity) as average_quantity_sold
150+
FROM
151+
transactions2 t
152+
WHERE
153+
t.product_id NOT IN (SELECT product_id FROM marketing_campaigns)
154+
)
155+
SELECT * FROM campaign_quantity
156+
UNION ALL
157+
SELECT * FROM outside_campaign_quantity;
49158
```
50159

51160
### 9. Compare the revenue generated by products inside the marketing campaigns to those outside the campaigns.
52161

53162
```sql
163+
WITH campaign_revenue AS (
164+
SELECT
165+
mc.campaign_name,
166+
ROUND(SUM(t.quantity * sc.price),2) as total_revenue
167+
FROM
168+
marketing_campaigns mc
169+
JOIN
170+
transactions2 t ON mc.product_id = t.product_id
171+
JOIN
172+
sustainable_clothing sc ON mc.product_id = sc.product_id
173+
GROUP BY
174+
mc.campaign_name
175+
),
176+
outside_campaign_revenue AS (
177+
SELECT
178+
'Outside Campaigns' as campaign_name,
179+
ROUND(SUM(t.quantity * sc.price),2) as total_revenue
180+
FROM
181+
transactions2 t
182+
JOIN
183+
sustainable_clothing sc ON t.product_id = sc.product_id
184+
WHERE
185+
t.product_id NOT IN (SELECT product_id FROM marketing_campaigns)
186+
)
187+
SELECT * FROM campaign_revenue
188+
UNION ALL
189+
SELECT * FROM outside_campaign_revenue;
54190
```
55191
### 10. Rank the products by their average daily quantity sold.
56192

57193
```sql
194+
WITH product_avg_quantity AS (
195+
SELECT
196+
sc.product_name,
197+
ROUND(AVG(t.quantity),2) as average_daily_quantity_sold
198+
FROM
199+
transactions2 t
200+
JOIN
201+
sustainable_clothing sc ON t.product_id = sc.product_id
202+
GROUP BY
203+
sc.product_name
204+
)
205+
SELECT *
206+
FROM product_avg_quantity
207+
ORDER BY average_daily_quantity_sold DESC;
58208
```
59209

60210

0 commit comments

Comments
 (0)