Mekki MOURADI

Data Analyst

Rabat, Maroc

À Propos

Data Analyst Junior avec une solide expérience en marketing numérique et des compétences approfondies dans l’utilisation de Microsoft Excel, SQL, Tableau Software et Python.

Walmart Sales Data Analysis with SQL​ (Jan-Feb-Mar)

Frame 28

Compétences & Outils

Description du projet

  • Analyse des ventes de 3 branches de Walmart sur une durée de 3 mois (janvier-février-mars).

Objectifs de l'analyse

  • Répondre à différentes business questions qui permettront une meilleure prise de décision.

  • Les questions portent sur différentes thématiques:
    • Général
    • Produits
    • Ventes
    • Consommateurs
				
					-- Create database
CREATE DATABASE IF NOT EXISTS walmartSales;


-- Create table
CREATE TABLE IF NOT EXISTS sales(
	invoice_id VARCHAR(30) NOT NULL PRIMARY KEY,
    branch VARCHAR(5) NOT NULL,
    city VARCHAR(30) NOT NULL,
    customer_type VARCHAR(30) NOT NULL,
    gender VARCHAR(30) NOT NULL,
    product_line VARCHAR(100) NOT NULL,
    unit_price DECIMAL(10,2) NOT NULL,
    quantity INT NOT NULL,
    tax_pct FLOAT(6,4) NOT NULL,
    total DECIMAL(12, 4) NOT NULL,
    date DATETIME NOT NULL,
    time TIME NOT NULL,
    payment VARCHAR(15) NOT NULL,
    cogs DECIMAL(10,2) NOT NULL,
    gross_margin_pct FLOAT(11,9),
    gross_income DECIMAL(12, 4),
    rating FLOAT(2, 1)
);

-- Data cleaning
SELECT
	*
FROM sales;


-- Add the time_of_day column
SELECT
	time,
	(CASE
		WHEN `time` BETWEEN "00:00:00" AND "12:00:00" THEN "Morning"
        WHEN `time` BETWEEN "12:01:00" AND "16:00:00" THEN "Afternoon"
        ELSE "Evening"
    END) AS time_of_day
FROM sales;


ALTER TABLE sales ADD COLUMN time_of_day VARCHAR(20);

-- For this to work turn off safe mode for update
-- Edit > Preferences > SQL Edito > scroll down and toggle safe mode
-- Reconnect to MySQL: Query > Reconnect to server
UPDATE sales
SET time_of_day = (
	CASE
		WHEN `time` BETWEEN "00:00:00" AND "12:00:00" THEN "Morning"
        WHEN `time` BETWEEN "12:01:00" AND "16:00:00" THEN "Afternoon"
        ELSE "Evening"
    END
);


-- Add day_name column
SELECT
	date,
	DAYNAME(date)
FROM sales;

ALTER TABLE sales ADD COLUMN day_name VARCHAR(10);

UPDATE sales
SET day_name = DAYNAME(date);


-- Add month_name column
SELECT
	date,
	MONTHNAME(date)
FROM sales;

ALTER TABLE sales ADD COLUMN month_name VARCHAR(10);

UPDATE sales
SET month_name = MONTHNAME(date);

-- --------------------------------------------------------------------
-- ---------------------------- Generic ------------------------------
-- --------------------------------------------------------------------
-- How many unique cities does the data have?
SELECT 
	DISTINCT city
FROM sales;

-- In which city is each branch?
SELECT 
	DISTINCT city,
    branch
FROM sales;

-- --------------------------------------------------------------------
-- ---------------------------- Product -------------------------------
-- --------------------------------------------------------------------

-- How many unique product lines does the data have?
SELECT
	DISTINCT product_line
FROM sales;


-- What is the most selling product line
SELECT
	SUM(quantity) as qty,
    product_line
FROM sales
GROUP BY product_line
ORDER BY qty DESC;

-- What is the most selling product line
SELECT
	SUM(quantity) as qty,
    product_line
FROM sales
GROUP BY product_line
ORDER BY qty DESC;

-- What is the total revenue by month
SELECT
	month_name AS month,
	SUM(total) AS total_revenue
FROM sales
GROUP BY month_name 
ORDER BY total_revenue;


-- What month had the largest COGS?
SELECT
	month_name AS month,
	SUM(cogs) AS cogs
FROM sales
GROUP BY month_name 
ORDER BY cogs;


-- What product line had the largest revenue?
SELECT
	product_line,
	SUM(total) as total_revenue
FROM sales
GROUP BY product_line
ORDER BY total_revenue DESC;

-- What is the city with the largest revenue?
SELECT
	branch,
	city,
	SUM(total) AS total_revenue
FROM sales
GROUP BY city, branch 
ORDER BY total_revenue;


-- What product line had the largest VAT?
SELECT
	product_line,
	AVG(tax_pct) as avg_tax
FROM sales
GROUP BY product_line
ORDER BY avg_tax DESC;


-- Fetch each product line and add a column to those product 
-- line showing "Good", "Bad". Good if its greater than average sales

SELECT 
	AVG(quantity) AS avg_qnty
FROM sales;

SELECT
	product_line,
	CASE
		WHEN AVG(quantity) > 6 THEN "Good"
        ELSE "Bad"
    END AS remark
FROM sales
GROUP BY product_line;


-- Which branch sold more products than average product sold?
SELECT 
	branch, 
    SUM(quantity) AS qnty
FROM sales
GROUP BY branch
HAVING SUM(quantity) > (SELECT AVG(quantity) FROM sales);


-- What is the most common product line by gender
SELECT
	gender,
    product_line,
    COUNT(gender) AS total_cnt
FROM sales
GROUP BY gender, product_line
ORDER BY total_cnt DESC;

-- What is the average rating of each product line
SELECT
	ROUND(AVG(rating), 2) as avg_rating,
    product_line
FROM sales
GROUP BY product_line
ORDER BY avg_rating DESC;

-- --------------------------------------------------------------------
-- --------------------------------------------------------------------

-- --------------------------------------------------------------------
-- -------------------------- Customers -------------------------------
-- --------------------------------------------------------------------

-- How many unique customer types does the data have?
SELECT
	DISTINCT customer_type
FROM sales;

-- How many unique payment methods does the data have?
SELECT
	DISTINCT payment
FROM sales;


-- What is the most common customer type?
SELECT
	customer_type,
	count(*) as count
FROM sales
GROUP BY customer_type
ORDER BY count DESC;

-- Which customer type buys the most?
SELECT
	customer_type,
    COUNT(*)
FROM sales
GROUP BY customer_type;


-- What is the gender of most of the customers?
SELECT
	gender,
	COUNT(*) as gender_cnt
FROM sales
GROUP BY gender
ORDER BY gender_cnt DESC;

-- What is the gender distribution per branch?
SELECT
	gender,
	COUNT(*) as gender_cnt
FROM sales
WHERE branch = "C"
GROUP BY gender
ORDER BY gender_cnt DESC;
-- Gender per branch is more or less the same hence, I don't think has
-- an effect of the sales per branch and other factors.

-- Which time of the day do customers give most ratings?
SELECT
	time_of_day,
	AVG(rating) AS avg_rating
FROM sales
GROUP BY time_of_day
ORDER BY avg_rating DESC;
-- Looks like time of the day does not really affect the rating, its
-- more or less the same rating each time of the day.alter


-- Which time of the day do customers give most ratings per branch?
SELECT
	time_of_day,
	AVG(rating) AS avg_rating
FROM sales
WHERE branch = "A"
GROUP BY time_of_day
ORDER BY avg_rating DESC;
-- Branch A and C are doing well in ratings, branch B needs to do a 
-- little more to get better ratings.


-- Which day fo the week has the best avg ratings?
SELECT
	day_name,
	AVG(rating) AS avg_rating
FROM sales
GROUP BY day_name 
ORDER BY avg_rating DESC;
-- Mon, Tue and Friday are the top best days for good ratings
-- why is that the case, how many sales are made on these days?



-- Which day of the week has the best average ratings per branch?
SELECT 
	day_name,
	COUNT(day_name) total_sales
FROM sales
WHERE branch = "C"
GROUP BY day_name
ORDER BY total_sales DESC;


-- --------------------------------------------------------------------
-- --------------------------------------------------------------------

-- --------------------------------------------------------------------
-- ---------------------------- Sales ---------------------------------
-- --------------------------------------------------------------------

-- Number of sales made in each time of the day per weekday 
SELECT
	time_of_day,
	COUNT(*) AS total_sales
FROM sales
WHERE day_name = "Sunday"
GROUP BY time_of_day 
ORDER BY total_sales DESC;
-- Evenings experience most sales, the stores are 
-- filled during the evening hours

-- Which of the customer types brings the most revenue?
SELECT
	customer_type,
	SUM(total) AS total_revenue
FROM sales
GROUP BY customer_type
ORDER BY total_revenue;

-- Which city has the largest tax/VAT percent?
SELECT
	city,
    ROUND(AVG(tax_pct), 2) AS avg_tax_pct
FROM sales
GROUP BY city 
ORDER BY avg_tax_pct DESC;

-- Which customer type pays the most in VAT?
SELECT
	customer_type,
	AVG(tax_pct) AS total_tax
FROM sales
GROUP BY customer_type
ORDER BY total_tax;

-- --------------------------------------------------------------------
-- --------------------------------------------------------------------
				
			
  • Vérifier la bonne syntax de mysql à postgresql
  • Vérifier les noms des colonnes
  • “column_name” lors de la création des colonnes sur postgre
  • Si
    ERROR: numeric field overflow
    DETAIL: A field with precision 3, scale 2 must round to an absolute value less than 10^1.
    CONTEXT: COPY sales, line 62, column rating: “10” 

    -> ne pas attribuer de restrictions à “numeric” : numeric(2,1) -> numeric
  • Vérifier datestamp en format anglais
  •  

Explorer la database 

ColumnDescriptionData Type
invoice_idInvoice of the sales madeVARCHAR(30)
branchBranch at which sales were madeVARCHAR(5)
cityThe location of the branchVARCHAR(30)
customer_typeThe type of the customerVARCHAR(30)
genderGender of the customer making purchaseVARCHAR(10)
product_lineProduct line of the product solfVARCHAR(100)
unit_priceThe price of each productDECIMAL(10, 2)
quantityThe amount of the product soldINT
tax_pctThe amount of tax on the purchaseNUMERIC
totalThe total cost of the purchaseDECIMAL(10, 2)
dateThe date on which the purchase was madeDATE
timeThe time at which the purchase was madeTIMESTAMP
paymentThe payment methodVARCHAR
cogsCost Of Goods soldDECIMAL(10, 2)
gross_margin_pctGross margin percentageNUMERIC(11, 9)
gross_incomeGross IncomeDECIMAL(10, 2)
ratingRatingNUMERIC

Aperçu du dataset

NB : Nécessité de transformer le datatype de la colonne 11 “date” de TIMESTAMP à DATE

				
					SELECT *
FROM sales
LIMIT 5;
				
			
invoice_idbranchcitycustomer_typegenderproduct_lineunit_pricequantitytax_pcttotaldatetimepaymentcogsgross_margin_pctgross_incomerating
371-85-5789BMandalayNormalMaleHealth and beauty87.98313.1970277.13702019-03-05 00:00:0010:40:00Ewallet263.944.76190476213.19705.1
273-16-6619BMandalayNormalMaleHome and lifestyle33.2023.320069.72002019-03-15 00:00:0012:20:00Credit card66.404.7619047623.32004.4
636-48-8204AYangonNormalMaleElectronic accessories34.5658.6400181.44002019-02-17 00:00:0011:15:00Ewallet172.804.7619047628.64009.9
549-59-1358AYangonMemberMaleSports and travel88.63313.2945279.18452019-03-02 00:00:0017:36:00Ewallet265.894.76190476213.29456
227-03-5010AYangonMemberFemaleHome and lifestyle52.59821.0360441.75602019-03-22 00:00:0019:20:00Credit card420.724.76190476221.03608.5

Colonnes “invoice_id” et “date” avec format modifié pour répondre aux besoins de l’analyse

				
					ALTER TABLE sales
ALTER COLUMN date TYPE DATE;

-- Vérification des modifications apportées

SELECT invoice_id, date
FROM sales
LIMIT 5;
				
			
invoice_iddate
371-85-57892019-03-05
273-16-66192019-03-15
636-48-82042019-02-17
549-59-13582019-03-02
227-03-50102019-03-22
Feature Engineering
  1. Add a new column named time_of_day to give insight of sales in the Morning, Afternoon and Evening. This will help answer the question on which part of the day most sales are made.
				
					-- ajout de la colonne "time_of_day" à la table "sales"

ALTER TABLE sales
ADD COLUMN time_of_day VARCHAR(20);

-- vérification de l'ajout de la colonne "time_of_day"

SELECT ROW_NUMBER() OVER () AS column_number
, column_name
FROM information_schema.columns
WHERE table_schema = 'public'
AND table_name = 'sales';
				
			
column_numbercolumn_name
1invoice_id
2branch
3city
4customer_type
5gender
6product_line
7unit_price
8quantity
9tax_pct
10total
11date
12time
13payment
14cogs
15gross_margin_pct
16gross_income
17rating
18time_of_day
				
					-- ajout des données à la colonne "time_of_day" en utilisant les données de la colonne "time"

UPDATE sales
SET time_of_day = (
	CASE
		WHEN time BETWEEN '00:00:00' AND '12:00:00' THEN 'Morning'
		WHEN time BETWEEN '12:00:01' AND '18:00:00' THEN 'Afternoon'
		ELSE 'Evening'
	END
);

-- vérification des modifications apportées

SELECT invoice_id, time_of_day
FROM sales
LIMIT 5;
				
			
invoice_idtime_of_day
371-85-5789Morning
273-16-6619Afternoon
636-48-8204Morning
549-59-1358Afternoon
227-03-5010Evening
  1. Add a new column named day_name that contains the extracted days of the week on which the given transaction took place (Mon, Tue, Wed, Thur, Fri). This will help answer the question on which week of the day each branch is busiest.
				
					-- ajout de la colonne "day_name"

ALTER TABLE sales ADD COLUMN day_name VARCHAR(20);

-- ajout des données à la colonne "day_name" en utilisant les données de la colonne "date"

UPDATE sales
SET day_name = (to_char(date,'day'));

-- vérification des modifications apportées

SELECT invoice_id, day_name
FROM sales
LIMIT 5;
				
			
dateday_name
2019-03-05tuesday
2019-03-15friday
2019-02-17sunday
2019-03-02saturday
2019-03-22friday
  1. Add a new column named month_name that contains the extracted months of the year on which the given transaction took place (Jan, Feb, Mar). Help determine which month of the year has the most sales and profit.
				
					-- ajout de la colonne "month_name"

ALTER TABLE sales ADD COLUMN month_name VARCHAR(20);

-- ajout des données à la colonne "month_name" en utilisant les données de la colonne "date"

UPDATE sales
SET month_name = (to_char(date,'month'));

-- vérification des modifications apportées

SELECT invoice_id, month_name
FROM sales
LIMIT 5;
				
			
datemonth_name
2019-03-05march
2019-03-15march
2019-02-17february
2019-03-02march
2019-03-22march
Generic Questions
  1. How many unique cities does the data have?
				
					SELECT DISTINCT city
FROMS sales;
				
			
city
Yangon
Naypyitaw
Mandalay
  1. In which city is each branch?
				
					SELECT DISTINCT city, branch
FROM sales
				
			
citybranch
YangonA
MandalayB
NaypyitawC
Product Questions
  1. How many unique product lines does the data have?
				
					SELECT COUNT(DISTINCT product_line) AS nb_unique_product_lines
FROM sales
LIMIT 5;

				
			
nb_unique_product_lines
6
  1. What is the most common payment method?
				
					SELECT payment, COUNT(payment) AS most_common_payment_method
FROM sales
GROUP BY payment
ORDER BY most_common_payment_method DESC
LIMIT 1;
				
			
paymentmost_common_payment_method
Ewallet345
  1. What are the 3 most selling product lines?

Most selling product_line by revenue

				
					SELECT product_line, ROUND(SUM(total),2) AS revenue
FROM sales
GROUP BY product_line
ORDER BY revenue DESC
LIMIT 3;
				
			
product_linerevenue
Food and beverages56144.84
Sports and travel55122.83
Electronic accessories54337.53

Most selling product_line by number of invoices

				
					SELECT product_line, COUNT(invoice_id) AS number_of_invoices
FROM sales
GROUP BY product_line
ORDER BY number_of_invoices DESC
LIMIT 3;
				
			
product_linenumber_of_invoices
Fashion accessories178
Food and beverages174
Electronic accessories170
  1. What is the total revenue by month?
				
					SELECT month_name, ROUND(SUM(total),2) AS total_revenue
FROM sales
GROUP BY month_name
ORDER BY total_revenue DESC;
				
			
month_nametotal_revenue
january 116291.87
march 109455.51
february 97219.37
  1. What month had the largest COGS?
				
					SELECT month_name, SUM(cogs) AS cogs
FROM sales
GROUP BY month_name
ORDER BY cogs DESC
LIMIT 1;
				
			
month_namecogs
january 110754.16
  1. What product line had the largest revenue?
				
					SELECT product_line, ROUND(SUM(total),2) AS revenue
FROM sales
GROUP BY product_line
ORDER BY revenue DESC
LIMIT 1;
				
			
product_linerevenue
Food and beverages56144.84
  1. What is the city with the largest revenue?
				
					SELECT city, ROUND(SUM(total),2) AS revenue
FROM sales
GROUP BY city
ORDER BY revenue DESC
LIMIT 1;
				
			
cityrevenue
Naypyitaw110568.71
  1. What product line had the largest VAT?
				
					SELECT product_line, ROUND(AVG(tax_pct),2) AS largest_vat
FROM sales
GROUP BY product_line
ORDER BY largest_VAT DESC
LIMIT 1;
				
			
product_linelargest_vat
Home and lifestyle16.03
  1. Fetch each product line and add a column to those product line showing "Good", "Bad". Good if its greater than average sales
				
					SELECT product_line, ROUND(SUM(total),2),
	CASE
	WHEN SUM(total) > AVG(total) THEN 'Good'
	ELSE 'Bad'
	END  AS total
FROM sales
GROUP BY product_line
ORDER BY total;
				
			
product_lineroundtotal
Fashion accessories54305.90Good
Electronic accessories54337.53Good
Health and beauty49193.74Good
Food and beverages56144.84Good
Sports and travel55122.83Good
Home and lifestyle53861.91Good
  1. Which branch sold more products than average product sold?
				
					SELECT branch, ROUND(AVG(quantity),2) AS avg_quantity
FROM sales
GROUP BY branch
HAVING AVG(quantity)>(SELECT ROUND(AVG(quantity),2) FROM sales);
				
			
branchavg_quantity
C5.58
  1. What is the most common product line by gender?
				
					WITH RankedProducts AS (
  SELECT
    gender,
    product_line, count(product_line) as quantity,
    ROW_NUMBER() OVER (PARTITION BY gender ORDER BY COUNT(*) DESC) AS row_num
  FROM
    sales
  GROUP BY
    gender, product_line
)
SELECT
  gender,
  product_line, quantity
FROM
  RankedProducts
WHERE
  row_num = 1;
				
			
genderproduct_linequantity
FemaleFashion accessories96
MaleHealth and beauty88
  1. What is the average rating of each product line?
				
					SELECT product_line, ROUND(AVG(rating),2) AS avg_rating
FROM sales
GROUP BY product_line
ORDER BY AVG(rating) DESC;
				
			
product_lineavg_rating
Food and beverages7.11
Fashion accessories7.03
Health and beauty7.00
Electronic accessories6.92
Sports and travel6.92
Home and lifestyle6.84
Sales Questions
  1. Number of sales made in each time of the day per weekday
				
					SELECT
    day_name,
    time_of_day,
    COUNT(invoice_id) AS total_invoices
FROM sales
GROUP BY day_name, time_of_day
ORDER BY
	CASE
		WHEN day_name = 'monday' THEN 1
		WHEN day_name = 'tuesday' THEN 2
		WHEN day_name = 'wednesday' THEN 3
		WHEN day_name = 'thursday' THEN 4
		WHEN day_name = 'friday' THEN 5
		WHEN day_name = 'saturday' THEN 6
		WHEN day_name = 'sunday' THEN 7
	END,
	CASE
		WHEN time_of_day = 'Morning' THEN 1
		WHEN time_of_day = 'Afternoon' THEN 2
		WHEN time_of_day = 'Evening' THEN 3
	END;
				
			
day_nametime_of_daytotal_invoices
mondayMorning21
mondayAfternoon76
mondayEvening28
tuesdayMorning36
tuesdayAfternoon71
tuesdayEvening51
wednesdayMorning22
wednesdayAfternoon81
wednesdayEvening40
thursdayMorning33
thursdayAfternoon76
thursdayEvening29
fridayMorning29
fridayAfternoon74
fridayEvening36
saturdayMorning28
saturdayAfternoon82
saturdayEvening54
sundayMorning22
sundayAfternoon70
sundayEvening41
  1. Which of the customer types brings the most revenue?
				
					SELECT customer_type, SUM(total) AS total
FROM sales
GROUP BY customer_type
ORDER BY total DESC
LIMIT 1;
				
			
customer_typerevenue
Member164223
  1. Which city has the largest tax percent/ VAT (Value Added Tax)?
				
					SELECT city, ROUND(AVG(tax_pct),2) AS avg_tax
FROM sales
GROUP BY city
ORDER BY avg_tax DESC
LIMIT 1;
				
			
cityavg_tax
Naypyitaw16.05
  1. Which customer type pays the most in VAT?
				
					SELECT customer_type, ROUND(AVG(tax_pct),2) AS avg_tax
FROM sales
GROUP BY customer_type
ORDER BY avg_tax DESC
LIMIT 1;
				
			
customer_typeavg_tax
Member15.61
Customer Questions
  1. How many unique customer types does the data have?
				
					SELECT COUNT(DISTINCT customer_type) AS nb_unique_customer_type
FROM sales;
				
			
nb_unique_customer_type
2
  1. How many unique payment methods does the data have?
				
					SELECT COUNT(DISTINCT payment) AS nb_unique_payment_method
FROM sales;
				
			
nb_unique_payment_method
3
  1. What is the most common customer type?
				
					SELECT customer_type, COUNT(customer_type) as number_customers
FROM sales
GROUP BY customer_type
ORDER BY number_customers DESC
LIMIT 1;
				
			
customer_typenumber_customers
Member501
  1. Which customer type buys the most?

By number of purchases

				
					SELECT customer_type, COUNT(invoice_id) as number_of_purchases
FROM sales
GROUP BY customer_type
ORDER BY number_of_purchases DESC
LIMIT 1;
				
			
customer_typenumber_of_purchases
Member501

By total spent

				
					SELECT customer_type, ROUND(SUM(total)) AS total_spent
FROM sales
GROUP BY customer_type
ORDER BY total_spent DESC
LIMIT 1;
				
			
customer_typetotal_spent
Member164223
  1. What is the gender of most of the customers?
				
					SELECT gender, COUNT(*) AS count_gender
FROM sales
GROUP BY gender
ORDER BY count_gender DESC
LIMIT 1;
				
			
gendercount_gender
Female501
  1. What is the gender distribution per branch?
				
					SELECT branch, gender, COUNT(gender) AS count_gender
FROM sales
GROUP BY branch, gender
ORDER BY
	CASE
		WHEN branch = 'A' THEN 1
		WHEN branch = 'B' THEN 2
		WHEN branch = 'C' THEN 3
	END,
	CASE
		WHEN gender = 'Female' THEN 1
		WHEN gender = 'Male' THEN 2
	END;
				
			
branchgendercount_gender
AFemale161
AMale179
BFemale162
BMale170
CFemale178
CMale150
  1. Which time of the day do customers give most ratings?
				
					SELECT time_of_day, COUNT(rating) AS number_ratings
FROM sales
GROUP BY time_of_day
ORDER BY number_ratings DESC
LIMIT 1;
				
			
time_of_daynumber_ratings
Afternoon530
  1. Which time of the day do customers give most ratings per branch?

By number of ratings

				
					WITH ratings_branch AS
(SELECT branch, time_of_day, COUNT(rating) AS number_ratings, ROW_NUMBER() OVER (PARTITION BY branch ORDER BY COUNT(rating) DESC) AS row_num
FROM sales
GROUP BY branch, time_of_day
)
SELECT branch, time_of_day, number_ratings
FROM ratings_branch
WHERE row_num=1;
				
			
branchtime_of_daynumber_ratings
AAfternoon186
BAfternoon163
CAfternoon181

By average rating

				
					WITH ratings_branch AS
(SELECT branch, time_of_day, ROUND(AVG(rating),2) AS avg_ratings, 
	ROW_NUMBER() OVER (PARTITION BY branch ORDER BY ROUND(AVG(rating),2) DESC) AS row_num
FROM sales
GROUP BY branch, time_of_day
)
SELECT branch, time_of_day, avg_ratings
FROM ratings_branch
WHERE row_num=1;
				
			
branchtime_of_dayavg_ratings
AAfternoon7.07
BMorning6.89
CAfternoon7.10
  1. Which day of the week has the best avg ratings?
				
					SELECT day_name, ROUND(AVG(rating),2) AS avg_ratings
FROM sales
GROUP BY day_name
ORDER BY avg_ratings DESC
LIMIT 1;
				
			
day_nameavg_ratings
monday7.15
  1. Which day of the week has the best average ratings per branch?
				
					WITH ratings_branch AS
(SELECT branch, day_name, ROUND(AVG(rating),2) AS avg_ratings, 
	ROW_NUMBER() OVER (PARTITION BY branch ORDER BY AVG(rating) DESC) AS row_num
FROM sales
GROUP BY branch, day_name
)
SELECT branch, day_name, avg_ratings
FROM ratings_branch
WHERE row_num=1;
				
			
branchday_nameavg_ratings
Afriday7.31
Bmonday7.34
Cfriday7.28