├── Createtables.sql ├── Dataset.zip ├── README.md ├── Ratings_Analysis.sql ├── Restaurant_Details.sql └── customer_demographics.sql /Createtables.sql: -------------------------------------------------------------------------------- 1 | --- Title :- Restaurant Ratings Analysis 2 | --- Created by :- Vinit Sangoi & Mausumi Meher 3 | --- Date :- 19-07-2022 4 | --- Tool used:- PostgreSQL 5 | 6 | /* 7 | 𝗜𝗻𝘁𝗿𝗼𝗱𝘂𝗰𝘁𝗶𝗼𝗻: 8 | ► In this project, we will be analyzing restaurant ratings data to gain insights into the performance of various restaurants. 9 | ► We will use SQL to extract, transform and analyze the data. 10 | ► The insights gained from this analysis will be used to understand the factors that influence a restaurant's rating and make recommendations for improvement. 11 | ► We will examine the relationship between different variables such as the location, cuisine and price range of the restaurants and their ratings. 12 | ► We will also do sentiment analysis to analyse most favorable restaurants of customers 13 | 14 | 𝗙𝗶𝗹𝗲𝗻𝗮𝗺𝗲: 𝗖𝗿𝗲𝗮𝘁𝗶𝗻𝗴 𝘁𝗮𝗯𝗹𝗲𝘀 15 | 16 | This SQL queries creates the important tables & imports the CSV files. 17 | */ 18 | 19 | --- 1) Creating customer_ratings Table 20 | 21 | CREATE TABLE Customer_Ratings ( 22 | Consumer_ID VARCHAR(50), 23 | Restaurant_ID VARCHAR(50), 24 | Overall_Rating INT, 25 | Food_Rating INT, 26 | Service_Rating INT 27 | ) 28 | 29 | COPY Customer_Ratings FROM 'C:\Program Files\PostgreSQL\14\Datasets\Restaurant_Ratings\ratings.csv' Header CSV 30 | 31 | Select * FROM customer_ratings 32 | 33 | 34 | --- 2) Creating customer_details table 35 | 36 | CREATE TABLE Customer_Details( 37 | Consumer_ID Varchar(50), 38 | City Varchar(50), 39 | State Varchar(50), 40 | Country Varchar(50), 41 | Latitude Decimal, 42 | Longitude Decimal, 43 | Smoker Varchar(50), 44 | Drink_Level Varchar(50), 45 | Transportation_Method Varchar(50), 46 | Marital_Status Varchar(50), 47 | Children Varchar(50), 48 | Age INT, 49 | Occupation Varchar(50), 50 | Budget Varchar(50) 51 | ) 52 | 53 | COPY Customer_Details FROM 'C:\Program Files\PostgreSQL\14\Datasets\Restaurant_Ratings\consumers.csv' Header CSV 54 | 55 | --- 3) Creating Customer Preference table 56 | 57 | CREATE TABLE Customer_Preference( 58 | Consumer_ID Varchar(50), 59 | Preferred_Cuisine Varchar(50) 60 | ) 61 | 62 | COPY Customer_Preference FROM 'C:\Program Files\PostgreSQL\14\Datasets\Restaurant_Ratings\consumer_preferences.csv' Header CSV 63 | 64 | 65 | --- 4) Creating restaurants table 66 | 67 | CREATE TABLE Restaurants ( 68 | Restaurant_ID Varchar(50), 69 | Name Varchar(100), 70 | City Varchar(50), 71 | State Varchar(50), 72 | Country Varchar(50), 73 | Zip_Code Varchar(50), 74 | Latitude Decimal, 75 | Longitude Decimal, 76 | Alcohol_Service Varchar(50), 77 | Smoking_Allowed Varchar(50), 78 | Price Varchar(50), 79 | Franchise Varchar(50), 80 | Area Varchar(50), 81 | Parking Varchar(100) 82 | ) 83 | 84 | COPY Restaurants FROM 'C:\Program Files\PostgreSQL\14\Datasets\Restaurant_Ratings\restaurants.csv' Header CSV 85 | 86 | 87 | --- Creating restaurant_cuisines Table 88 | 89 | CREATE TABLE restaurant_cuisines ( 90 | Restaurant_ID Varchar(50), 91 | Cuisine Varchar(50) 92 | ) 93 | 94 | COPY restaurant_cuisines FROM 'C:\Program Files\PostgreSQL\14\Datasets\Restaurant_Ratings\restaurant_cuisines.csv' Header CSV -------------------------------------------------------------------------------- /Dataset.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/mausumi45/Resturant-Rating-Analysis/dae24b91c8da3deefff81bef8953a5eb3b145201/Dataset.zip -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Resturant-Rating-Analysis : 2 | ![istockphoto-1157450708-612x612](https://user-images.githubusercontent.com/98810351/210957506-bae17bd2-02be-43b1-bb8e-d850e25db922.jpg) 3 | ## About the dataset : 4 | 5 | 🍸 We found this dataset from Maven Analytics. Restaurant ratings in Mexico by real consumers from 2012 with 5 CSV Files. 6 | 7 | 🍸Customer Details: The table contains customer information. 8 | 9 | 🍸 Customer preference: This table contains customer cuisine preferences. 10 | 11 | 🍸 Restaurants: The dataset includes restaurant details 12 | 13 | 🍸 Restaurant's Cuisine: The table contains cuisines offered by each restaurant. 14 | 15 | 🍸 Customer Ratings: This dataset is the main table in the project. It includes information regarding customer ratings. 16 | ## 𝗜𝗻𝘁𝗿𝗼𝗱𝘂𝗰𝘁𝗶𝗼𝗻: 17 | 18 | 🍰 In this project, we will be analyzing restaurant ratings data to gain insights into the performance of various restaurants. 19 | 20 | 🍰 We will use SQL to extract, transform and analyze the data. 21 | 22 | 🍰 The insights gained from this analysis will be used to understand the factors that influence a restaurant's rating and make recommendations for improvement. 23 | 24 | 🍰 We will examine the relationship between different variables such as the location, cuisine and price range of the restaurants and their ratings. 25 | 26 | 𝗔𝗽𝗽𝗿𝗼𝗮𝗰𝗵: 27 | 28 | 🍕 Acquired the restaurant ratings data from a publicly available source and import it into a SQL database. 29 | 30 | 🍕 Used SQL to clean the data and ensure that it is in a format that can be easily analyzed. This will involve tasks such as removing duplicate records, handling missing values, and standardizing data formats. 31 | 32 | 🍕 Use SQL to extract relevant information from the data, such as the average rating for each restaurant, the number of reviews, and the location of the restaurant. 33 | 34 | 🍕 Analyzed the datasets using advanced SQL to identify patterns and trends in the data. 35 | 36 | 🍕 We analyzed various metrics using SQL commands & functions. 37 | 38 | 🍕 We used the insights gained from the analysis to make recommendations for improvement for the restaurants, and suggest ways in which the data can be used to drive business decisions. 39 | 40 | 𝗦𝗤𝗟 𝗙𝘂𝗻𝗰𝘁𝗶𝗼𝗻𝘀 𝘂𝘀𝗲𝗱: 41 | 42 | In this project, we used various SQL commands & functions like: 43 | 44 | - DDL 45 | 46 | - DML 47 | 48 | - Joins 49 | 50 | - Subqueries 51 | 52 | - Multiple joins 53 | 54 | - Case statements 55 | 56 | - Logical conditions 57 | 58 | - Nested subqueries 59 | 60 | - Windows functions 61 | 62 | 𝗞𝗲𝘆 𝗜𝗻𝘀𝗶𝗴𝗵𝘁𝘀: 63 | 64 | 65 | 66 | 𝘾𝙪𝙨𝙩𝙤𝙢𝙚𝙧 𝙙𝙚𝙢𝙤𝙜𝙧𝙖𝙥𝙝𝙞𝙘𝙨: 67 | 🍟 62% customers are from "San Luis Potosi". 68 | 69 | 🍟 70% customers have medium budget & 0.4% customers have high budget. 70 | 71 | 🍟 Most of the drinkers & smokers are students and they are casual drinkers or social drinkers. 72 | 73 | 🍟 80% of our customers are in the age bucket of 18-25 74 | 75 | 🍟 Most preferred cuisines are Mexican, American, Pizzeria, Cafeteria & Coffee shop. 76 | 77 | 78 | 79 | 𝙍𝙚𝙨𝙩𝙖𝙪𝙧𝙖𝙣𝙩 𝘿𝙚𝙩𝙖𝙞𝙡𝙨: 80 | 81 | 🧁There are a total 129 restaurants & majority are in the city of "San Luis Potosi". 82 | 83 | 🧁Only 41 restaurants are serving drinks & 65 restaurants don't have parking. 84 | 85 | 🧁Most restaurants offer cuisines like Mexican, Bar, Cafeteria, Fast Food, Brewery, Seafood, Burgers. 86 | 87 | 🧁18% of restaurants are of High budget, 49% of them are of Medium budget & 33% are low budget. 88 | 89 | 90 | 91 | 𝙍𝙖𝙩𝙞𝙣𝙜𝙨 𝙖𝙣𝙖𝙡𝙮𝙨𝙞𝙨: 92 | 93 | 🍷 There are 26 restaurants who received an average overall rating of more than 1.50. 94 | 95 | 🍷 44% responses from the customers were positive for the food experience. 96 | 97 | 🍷 22% responses from the customers were negative for overall experience. 98 | 99 | 🍷 131 customers are visiting their local restaurants & 14 customers are visiting outside of their locality. 100 | 101 | 🍷 Customers from cities of Ciudad Victoria, Cuernavaca & jiutepec are visiting restaurants of San Luis Potosi. 102 | 103 | 🍷 We analyzed the best restaurants for each cuisine based on average ratings. 104 | 105 | 🍷 We analyzed bad restaurants for each cuisine based on average ratings. 106 | 107 | 🍷 For overall & food experience best average cuisine is International & for food experience it is Mexican. 108 | 109 | 🍷 There are 293 responses (25%) of customers who gave the highest ratings in all the experiences. 110 | 111 | 112 | 113 | 𝗦𝘁𝗿𝗮𝘁𝗲𝗴𝗶𝗲𝘀: 114 | 115 | ⭐ We found that the average rating for food experience in our dataset was around 1.21/2.00. This indicates that overall, customers were pleased with their dining experiences. But some restaurants didn't receive good ratings for the service. So the restaurants should focus on improving their service experience. 116 | 117 | ⭐ Most of the good restaurants are in the city of San Luis Potosi for which outsiders were travelling to this city. We can improve our food & services in other cities as well. 118 | 119 | ⭐ American cuisine is the second most preferred cuisine by customers but we don't have that many restaurants with american cuisine. We can improve the business in that segment as well. 120 | 121 | ⭐ Students & teenagers are more into drinking & smoking so we can plan some marketing strategy for them like special student entry or student discount to acquire customers. 122 | 123 | 124 | 125 | 126 | 127 | 128 | 129 | 130 | -------------------------------------------------------------------------------- /Ratings_Analysis.sql: -------------------------------------------------------------------------------- 1 | --- Title :- Restaurant Ratings Analysis 2 | --- Created by :- Vinit Sangoi & Mausumi Meher 3 | --- Date :- 19-01-2023 4 | --- Tool used:- PostgreSQL 5 | 6 | /* 7 | 𝗜𝗻𝘁𝗿𝗼𝗱𝘂𝗰𝘁𝗶𝗼𝗻: 8 | ► In this project, we will be analyzing restaurant ratings data to gain insights into the performance of various restaurants. 9 | ► We will use SQL to extract, transform and analyze the data. 10 | ► The insights gained from this analysis will be used to understand the factors that influence a restaurant's rating and make recommendations for improvement. 11 | ► We will examine the relationship between different variables such as the location, cuisine and price range of the restaurants and their ratings. 12 | ► We will also do sentiment analysis to analyse most favorable restaurants of customers 13 | 14 | 𝗙𝗶𝗹𝗲𝗻𝗮𝗺𝗲: 𝗥𝗮𝘁𝗶𝗻𝗴𝘀 𝗔𝗻𝗮𝗹𝘆𝘀𝗶𝘀 15 | 16 | This SQL queries analyzes the ratings given by customers to restaurants. This helps to understand the customer choice & restaurants performance better. 17 | */ 18 | 19 | 20 | --- Q27) Ratings given by customer for restaurants 21 | SELECT 22 | b.consumer_id, 23 | a.name, 24 | b.overall_rating, 25 | b.food_rating, 26 | b.service_rating 27 | FROM restaurants as a 28 | INNER JOIN customer_ratings as b 29 | ON a.restaurant_id = b.restaurant_id 30 | ORDER BY b.restaurant_id 31 | 32 | 33 | --- Q28) Average ratings of each restaurant including it's cuisine type 34 | SELECT 35 | a.name, 36 | ROUND(AVG(b.overall_rating),2)as overall_Rating, 37 | ROUND(AVG(b.food_rating),2)as food_rating, 38 | ROUND(AVG(b.service_rating),2)as service_rating, 39 | c.cuisine 40 | FROM restaurants as a 41 | INNER JOIN customer_ratings as b 42 | ON a.restaurant_id = b.restaurant_id 43 | INNER JOIN restaurant_cuisines AS c 44 | ON a.restaurant_id = c.restaurant_id 45 | GROUP BY a.name,c.cuisine 46 | ORDER BY a.name 47 | 48 | --- Q29) Creating new columns for sentiment analysis 49 | ALTER TABLE customer_ratings ADD COLUMN overall_senti Varchar(50) 50 | ALTER TABLE customer_ratings ADD COLUMN food_senti Varchar(50) 51 | ALTER TABLE customer_ratings ADD COLUMN service_senti Varchar(50) 52 | 53 | SELECT * FROM customer_ratings 54 | 55 | 56 | --- Q30) Updating the new columns with the sentiments 57 | 58 | UPDATE customer_ratings 59 | SET overall_senti = CASE WHEN overall_rating = 0 then 'Negative' 60 | WHEN overall_rating = 1 then 'Neutral' 61 | WHEN overall_rating = 2 then 'Positive' 62 | END 63 | WHERE overall_senti is null 64 | 65 | UPDATE customer_ratings 66 | SET food_senti = CASE WHEN food_rating = 0 then 'Negative' 67 | WHEN food_rating = 1 then 'Neutral' 68 | WHEN food_rating = 2 then 'Positive' 69 | END 70 | WHERE food_senti is null 71 | 72 | UPDATE customer_ratings 73 | SET service_senti = CASE WHEN service_rating = 0 then 'Negative' 74 | WHEN service_rating = 1 then 'Neutral' 75 | WHEN service_rating = 2 then 'Positive' 76 | END 77 | WHERE service_senti is null 78 | 79 | 80 | --- Q31) Conduct a sentimental analysis of total count of customers 81 | CREATE VIEW overall AS ( 82 | SELECT 83 | overall_senti, 84 | count(consumer_id) as total_customers 85 | FROM customer_ratings 86 | GROUP BY overall_senti 87 | 88 | 89 | CREATE VIEW food AS ( 90 | SELECT 91 | food_senti, 92 | count(consumer_id) as total_customers 93 | FROM customer_ratings 94 | GROUP BY food_senti 95 | 96 | 97 | CREATE VIEW service AS ( 98 | SELECT 99 | service_senti, 100 | count(consumer_id) as total_customers 101 | FROM customer_ratings 102 | GROUP BY service_senti 103 | 104 | 105 | SELECT 106 | a.overall_senti as Sentiment, 107 | a.total_customers as Overall_Rating, 108 | b.total_customers as food_Rating, 109 | c.total_customers as service_Rating 110 | FROM overall as a 111 | INNER JOIN food as b 112 | ON a.overall_senti = b.food_senti 113 | INNER JOIN service as c 114 | ON a.overall_senti = c.service_senti 115 | 116 | 117 | --- Q32) List of Customers visiting local or outside restaurants 118 | 119 | SELECT 120 | a.consumer_id, 121 | b.city as customer_city, 122 | c.name, 123 | c.city as restaurant_city, 124 | a.overall_senti, 125 | a.food_senti, 126 | a.service_senti, 127 | CASE WHEN b.city = c.city THEN 'Local' ELSE 'Outside' END as Location_preference 128 | FROM customer_ratings as a 129 | INNER JOIN customer_details as b 130 | ON a.consumer_id = b.consumer_id 131 | INNER JOIN restaurants as c 132 | ON a.restaurant_id = c.restaurant_id 133 | 134 | 135 | --- Q33) Count of customers visiting local and outside restaurants 136 | 137 | SELECT 138 | Location_preference, 139 | count(*) as total_customers, 140 | count( distinct id) as distinct_customers 141 | FROM (SELECT 142 | a.consumer_id as id, 143 | b.city as customer_city, 144 | c.name, 145 | c.city as restaurant_city, 146 | a.overall_senti, 147 | a.food_senti, 148 | a.service_senti, 149 | CASE WHEN b.city = c.city THEN 'Local' ELSE 'Outside' END as Location_preference 150 | FROM customer_ratings as a 151 | INNER JOIN customer_details as b 152 | ON a.consumer_id = b.consumer_id 153 | INNER JOIN restaurants as c 154 | ON a.restaurant_id = c.restaurant_id ) as cte 155 | GROUP BY Location_preference 156 | 157 | 158 | --- Q34) Trend of customers visiting outside restaurants 159 | 160 | SELECT 161 | customer_id, 162 | customer_city, 163 | restaurant_city, 164 | concat_ws(' - ',customer_city , restaurant_city) as direction, 165 | restaurant_name 166 | FROM (SELECT 167 | a.consumer_id as customer_id, 168 | b.city as customer_city, 169 | c.name as restaurant_name, 170 | c.city as restaurant_city, 171 | a.overall_senti, 172 | a.food_senti, 173 | a.service_senti, 174 | CASE WHEN b.city = c.city THEN 'Local' ELSE 'Outside' END as Location_preference 175 | FROM customer_ratings as a 176 | INNER JOIN customer_details as b 177 | ON a.consumer_id = b.consumer_id 178 | INNER JOIN restaurants as c 179 | ON a.restaurant_id = c.restaurant_id ) as cte 180 | WHERE Location_preference = 'Outside' 181 | 182 | 183 | 184 | --- Q35) Count of direction trend from above query 185 | 186 | SELECT 187 | direction, 188 | count(customer_id) as total_customers 189 | 190 | FROM (SELECT 191 | customer_id, 192 | customer_city, 193 | restaurant_city, 194 | concat_ws(' - ',customer_city , restaurant_city) as direction, 195 | restaurant_name 196 | 197 | FROM (SELECT 198 | a.consumer_id as customer_id, 199 | b.city as customer_city, 200 | c.name as restaurant_name, 201 | c.city as restaurant_city, 202 | a.overall_senti, 203 | a.food_senti, 204 | a.service_senti, 205 | CASE WHEN b.city = c.city THEN 'Local' ELSE 'Outside' END as Location_preference 206 | FROM customer_ratings as a 207 | INNER JOIN customer_details as b 208 | ON a.consumer_id = b.consumer_id 209 | INNER JOIN restaurants as c 210 | ON a.restaurant_id = c.restaurant_id ) as cte 211 | WHERE Location_preference = 'Outside' ) cte2 212 | GROUP BY direction 213 | 214 | 215 | --- Q36) Cuisine preferences vs cuisine consumed 216 | 217 | SELECT 218 | a.consumer_id, 219 | string_agg(b.preferred_cuisine,',') as customer_preferences, 220 | d.name, 221 | c.cuisine as restaurant_cuisine 222 | FROM customer_ratings as a 223 | INNER JOIN customer_preference as b 224 | ON a.consumer_id = b.consumer_id 225 | INNER JOIN restaurant_cuisines as c 226 | ON a.restaurant_id = c.restaurant_id 227 | INNER JOIN restaurants as d 228 | ON a.restaurant_id = d.restaurant_id 229 | GROUP BY a.consumer_id, d.name, c.cuisine 230 | 231 | 232 | --- Q37) Best restaurants for each cuisines by different ratings 233 | CREATE VIEW average_analysis as ( 234 | SELECT 235 | a.name, 236 | ROUND(AVG(b.overall_rating),2)as overall_Rating, 237 | ROUND(AVG(b.food_rating),2)as food_rating, 238 | ROUND(AVG(b.service_rating),2)as service_rating, 239 | c.cuisine 240 | FROM restaurants as a 241 | INNER JOIN customer_ratings as b 242 | ON a.restaurant_id = b.restaurant_id 243 | INNER JOIN restaurant_cuisines AS c 244 | ON a.restaurant_id = c.restaurant_id 245 | GROUP BY a.name,c.cuisine 246 | ORDER BY c.cuisine) 247 | 248 | 249 | CREATE VIEW best as ( 250 | SELECT 251 | cuisine, 252 | First_value(name) OVER(partition by cuisine ORDER BY overall_rating desc) as best_for_overall, 253 | First_value(name) OVER(partition by cuisine ORDER BY food_rating desc) as best_for_food, 254 | First_value(name) OVER(partition by cuisine ORDER BY service_rating desc) as best_for_service 255 | FROM average_analysis 256 | 257 | SELECT 258 | * 259 | FROM best 260 | GROUP BY cuisine, best_for_overall, best_for_food, best_for_service 261 | ORDER BY cuisine 262 | 263 | 264 | --- Q38) Best restaurants for each cuisines by different ratings 265 | 266 | CREATE VIEW count_cuisines as ( 267 | SELECT 268 | cuisine, 269 | count(cuisine) as count 270 | FROM average_analysis 271 | GROUP BY cuisine ) 272 | 273 | CREATE VIEW bad as ( 274 | SELECT 275 | cuisine, 276 | First_value(name) OVER(partition by cuisine ORDER BY overall_rating ) as bad_for_overall, 277 | First_value(name) OVER(partition by cuisine ORDER BY food_rating ) as bad_for_food, 278 | First_value(name) OVER(partition by cuisine ORDER BY service_rating ) as bad_for_service 279 | FROM ( 280 | SELECT 281 | a.name, 282 | ROUND(AVG(a.overall_rating),2)as overall_Rating, 283 | ROUND(AVG(a.food_rating),2)as food_rating, 284 | ROUND(AVG(a.service_rating),2)as service_rating, 285 | a.cuisine, 286 | cc.count 287 | FROM average_analysis as a 288 | INNER JOIN count_cuisines as cc 289 | ON a.cuisine = cc.cuisine 290 | WHERE cc.count > 1 291 | GROUP BY a.name,a.cuisine,cc.count 292 | ORDER BY a.cuisine ) as least ) 293 | 294 | 295 | SELECT 296 | * 297 | FROM bad 298 | GROUP BY cuisine, bad_for_overall, bad_for_food, bad_for_service 299 | ORDER BY cuisine 300 | 301 | 302 | --- Q39) Best cuisines by different ratings 303 | 304 | SELECT 305 | First_value(cuisine) OVER(ORDER BY overall_rating desc) as overall, 306 | First_value(cuisine) OVER(ORDER BY food_rating desc) as food, 307 | First_value(cuisine) OVER(ORDER BY service_rating desc) as service 308 | FROM average_analysis 309 | LIMIT 1 310 | 311 | 312 | --- Q40) Total customers with highest ratings in all different criteria 313 | SELECT 314 | count(consumer_id) as total_customers 315 | FROM customer_ratings 316 | WHERE overall_rating = 2 and 317 | food_rating = 2 and 318 | service_rating = 2 -------------------------------------------------------------------------------- /Restaurant_Details.sql: -------------------------------------------------------------------------------- 1 | --- Title :- Restaurant Ratings Analysis 2 | --- Created by :- Vinit Sangoi & Mausumi Meher 3 | --- Date :- 19-01-2023 4 | --- Tool used:- PostgreSQL 5 | 6 | /* 7 | 𝗜𝗻𝘁𝗿𝗼𝗱𝘂𝗰𝘁𝗶𝗼𝗻: 8 | ► In this project, we will be analyzing restaurant ratings data to gain insights into the performance of various restaurants. 9 | ► We will use SQL to extract, transform and analyze the data. 10 | ► The insights gained from this analysis will be used to understand the factors that influence a restaurant's rating and make recommendations for improvement. 11 | ► We will examine the relationship between different variables such as the location, cuisine and price range of the restaurants and their ratings. 12 | ► We will also do sentiment analysis to analyse most favorable restaurants of customers 13 | 14 | 𝗙𝗶𝗹𝗲𝗻𝗮𝗺𝗲: 𝗥𝗲𝘀𝘁𝗮𝘂𝗿𝗮𝗻𝘁 𝗗𝗲𝘁𝗮𝗶𝗹𝘀 15 | 16 | This SQL queries analyzes the restaurants & their cuisine type. This helps to understand the types of restaurants & their cuisines. 17 | */ 18 | 19 | 20 | 21 | --- Q16) Total restaurants in each state 22 | SELECT 23 | State, 24 | count(restaurant_id) as Total_restaurant 25 | FROM restaurants 26 | GROUP BY State 27 | Order BY Total_restaurant DESC 28 | 29 | --- Q17) Total restaurants in each city 30 | SELECT 31 | city, 32 | count(restaurant_id) as Total_restaurant 33 | FROM restaurants 34 | GROUP BY city 35 | Order BY Total_restaurant DESC 36 | 37 | --- Q18) Restaurants count by alcohol service 38 | SELECT 39 | alcohol_service, 40 | count(restaurant_id) as Total_restaurant 41 | FROM restaurants 42 | GROUP BY alcohol_service 43 | Order BY Total_restaurant DESC 44 | 45 | --- Q19) Restaurants count by smoking allowed 46 | SELECT 47 | smoking_allowed, 48 | count(restaurant_id) as Total_restaurant 49 | FROM restaurants 50 | GROUP BY smoking_allowed 51 | Order BY Total_restaurant DESC 52 | 53 | --- Q20) Alcohol & Smoking analysis 54 | SELECT 55 | alcohol_service,smoking_allowed, 56 | count(restaurant_id) as Total_restaurant 57 | FROM restaurants 58 | GROUP BY alcohol_service,smoking_allowed 59 | Order BY Total_restaurant DESC 60 | 61 | --- Q21)Restaurants count by Price 62 | SELECT 63 | price, 64 | count(restaurant_id) as Total_restaurant 65 | FROM restaurants 66 | GROUP BY price 67 | Order BY Total_restaurant DESC 68 | 69 | --- Q22)Restaurants count by packing 70 | SELECT 71 | parking, 72 | count(restaurant_id) as Total_restaurant 73 | FROM restaurants 74 | GROUP BY parking 75 | Order BY Total_restaurant DESC 76 | 77 | --- Q23) Count of Restaurants by cuisines 78 | SELECT 79 | cuisine, 80 | count(restaurant_id) AS Total_restaurant 81 | FROM restaurant_cuisines 82 | GROUP BY cuisine 83 | ORDER BY Total_restaurant DESC 84 | 85 | --- Q24) Preferred cuisines of each customer 86 | SELECT 87 | name, 88 | count(cuisine) AS Total_cuisines, 89 | String_agg (cuisine, ',') as Cuisines 90 | FROM restaurant_cuisines as a 91 | INNER JOIN restaurants as b 92 | ON a.restaurant_id = b.restaurant_id 93 | GROUP BY name 94 | ORDER BY Total_cuisines DESC 95 | 96 | 97 | --- Q25) Restaurant price analysis for each cuisine 98 | 99 | SELECT 100 | b.cuisine, 101 | SUM(CASE WHEN a.price = 'High' Then 1 Else 0 END) AS High, 102 | SUM(CASE WHEN a.price = 'Medium' Then 1 Else 0 END) AS Medium, 103 | SUM(CASE WHEN a.price = 'Low' Then 1 Else 0 END) AS Low 104 | FROM restaurants AS a 105 | INNER JOIN restaurant_cuisines AS b 106 | ON a.restaurant_id = b.restaurant_id 107 | GROUP BY b.cuisine 108 | ORDER BY b.cuisine 109 | 110 | 111 | --- Q26) Finding out count of each cuisine in each state 112 | 113 | SELECT 114 | b.cuisine, 115 | SUM(CASE WHEN a.state = 'Morelos' Then 1 Else 0 END) AS Morelos, 116 | SUM(CASE WHEN a.state = 'San Luis Potosi' Then 1 Else 0 END) AS San_Luis_Potosi, 117 | SUM(CASE WHEN a.state = 'Tamaulipas' Then 1 Else 0 END) AS Tamaulipas 118 | FROM restaurants AS a 119 | INNER JOIN restaurant_cuisines AS b 120 | ON a.restaurant_id = b.restaurant_id 121 | GROUP BY b.cuisine 122 | ORDER BY b.cuisine -------------------------------------------------------------------------------- /customer_demographics.sql: -------------------------------------------------------------------------------- 1 | --- Title :- Restaurant Ratings Analysis 2 | --- Created by :- Vinit Sangoi & Mausumi Meher 3 | --- Date :- 19-01-2023 4 | --- Tool used:- PostgreSQL 5 | 6 | /* 7 | 𝗜𝗻𝘁𝗿𝗼𝗱𝘂𝗰𝘁𝗶𝗼𝗻: 8 | ► In this project, we will be analyzing restaurant ratings data to gain insights into the performance of various restaurants. 9 | ► We will use SQL to extract, transform and analyze the data. 10 | ► The insights gained from this analysis will be used to understand the factors that influence a restaurant's rating and make recommendations for improvement. 11 | ► We will examine the relationship between different variables such as the location, cuisine and price range of the restaurants and their ratings. 12 | ► We will also do sentiment analysis to analyse most favorable restaurants of customers 13 | 14 | 𝗙𝗶𝗹𝗲𝗻𝗮𝗺𝗲: 𝗖𝘂𝘀𝘁𝗼𝗺𝗲𝗿 𝗗𝗲𝗺𝗼𝗴𝗿𝗮𝗽𝗵𝗶𝗰𝘀 𝗔𝗻𝗮𝗹𝘆𝘀𝗶𝘀 15 | 16 | This SQL queries analyzes the customers & their cuisines preferences. This helps to understand the types of customers & their preferences. 17 | */ 18 | 19 | 20 | --- Q1) Total Customers in each state 21 | SELECT 22 | State, 23 | count(consumer_id) as Total_Customers 24 | FROM customer_details 25 | GROUP BY State 26 | Order BY Total_Customers DESC 27 | 28 | 29 | --- Q2) Total Customers in each city 30 | SELECT 31 | city, 32 | count(consumer_id) as Total_Customers 33 | FROM customer_details 34 | GROUP BY city 35 | Order BY Total_Customers DESC 36 | 37 | --- Q2) Total Customers in each city 38 | SELECT 39 | city, 40 | count(consumer_id) as Total_Customers 41 | FROM customer_details 42 | GROUP BY city 43 | Order BY Total_Customers DESC 44 | 45 | 46 | --- Q3) Budget level of customers 47 | SELECT 48 | budget, 49 | count(consumer_id) as Total_Customers 50 | FROM customer_details 51 | WHERE budget is not null 52 | GROUP BY budget 53 | 54 | --- Q4) Total Smokers by Occupation 55 | SELECT 56 | occupation, 57 | count(consumer_id) as Smokers 58 | FROM customer_details 59 | WHERE smoker = 'Yes' 60 | GROUP BY occupation 61 | 62 | --- Q5) Drinking level of students 63 | SELECT 64 | drink_level, 65 | count(consumer_id) as student_count 66 | FROM customer_details 67 | WHERE occupation = 'Student' and occupation is not null 68 | GROUP BY drink_level 69 | 70 | --- Q6) Transportation methods of customers 71 | SELECT 72 | transportation_method, 73 | count(consumer_id) as Total_Customers 74 | FROM customer_details 75 | WHERE transportation_method is not null 76 | GROUP BY transportation_method 77 | Order BY Total_Customers DESC 78 | 79 | --- Q7) Adding Age Bucket Column 80 | ALTER TABLE customer_details 81 | ADD COLUMN Age_Bucket Varchar(50) 82 | 83 | 84 | --- Q8) Updating the Age Bucket column with case when condition 85 | UPDATE customer_details 86 | SET age_bucket = CASE WHEN age > 60 then '61 and Above' 87 | WHEN age > 40 then '41 - 60' 88 | WHEN age > 25 then '26 - 40' 89 | WHEN age >= 18 then '18 - 25' 90 | END 91 | WHERE age_bucket is null 92 | 93 | 94 | --- Q9) Total customers in each age bucket 95 | SELECT 96 | age_bucket, 97 | count(consumer_id) as Total_Customers 98 | FROM customer_details 99 | GROUP BY age_bucket 100 | Order BY age_bucket 101 | 102 | 103 | --- Q10) Total customers count & smokers count in each age percent 104 | SELECT 105 | age_bucket, 106 | count(consumer_id) as total, 107 | count(case when smoker = 'Yes' Then consumer_id end) as smokerscount 108 | FROM customer_details 109 | GROUP BY age_bucket 110 | Order BY age_bucket 111 | 112 | 113 | SELECT * FROM customer_preference 114 | 115 | --- Q11) Top 20 preferred cuisines 116 | SELECT 117 | preferred_cuisine, 118 | count(consumer_id) AS total_customers 119 | FROM customer_preference 120 | GROUP BY preferred_cuisine 121 | ORDER BY total_customers DESC 122 | LIMIT 20 123 | 124 | 125 | --- Q12) Preferred cuisines of each customer 126 | SELECT 127 | consumer_id, 128 | count(preferred_cuisine) AS total_cuisines, 129 | String_agg (preferred_cuisine, ',') as Cuisines 130 | FROM customer_preference 131 | GROUP BY consumer_id 132 | ORDER BY total_cuisines DESC 133 | 134 | 135 | --- Q13) Customer Budget analysis for each cuisine 136 | 137 | SELECT 138 | b.preferred_cuisine, 139 | SUM(CASE WHEN a.budget = 'High' Then 1 Else 0 END) AS High, 140 | SUM(CASE WHEN a.budget = 'Medium' Then 1 Else 0 END) AS Medium, 141 | SUM(CASE WHEN a.budget = 'Low' Then 1 Else 0 END) AS Low 142 | FROM customer_details AS a 143 | INNER JOIN customer_preference AS b 144 | ON a.consumer_id = b.consumer_id 145 | GROUP BY b.preferred_cuisine 146 | ORDER BY b.preferred_cuisine 147 | 148 | 149 | --- Q14) Finding out count of each cuisine in each state 150 | 151 | SELECT 152 | a.state, 153 | b.preferred_cuisine 154 | FROM customer_details AS a 155 | INNER JOIN customer_preference AS b 156 | ON a.consumer_id = b.consumer_id 157 | GROUP BY a.state, b.preferred_cuisine 158 | ORDER BY a.state 159 | 160 | SELECT 161 | b.preferred_cuisine, 162 | SUM(CASE WHEN a.state = 'Morelos' Then 1 Else 0 END) AS Morelos, 163 | SUM(CASE WHEN a.state = 'San Luis Potosi' Then 1 Else 0 END) AS San_Luis_Potosi, 164 | SUM(CASE WHEN a.state = 'Tamaulipas' Then 1 Else 0 END) AS Tamaulipas 165 | FROM customer_details AS a 166 | INNER JOIN customer_preference AS b 167 | ON a.consumer_id = b.consumer_id 168 | GROUP BY b.preferred_cuisine 169 | ORDER BY b.preferred_cuisine 170 | 171 | 172 | --- Q15) Finding out count of each cuisine in each age bucket 173 | SELECT 174 | b.preferred_cuisine, 175 | SUM(CASE WHEN a.age_bucket = '18 - 25' Then 1 Else 0 END) AS "18 - 25", 176 | SUM(CASE WHEN a.age_bucket = '26 - 40' Then 1 Else 0 END) AS "26 - 40", 177 | SUM(CASE WHEN a.age_bucket = '41 - 60' Then 1 Else 0 END) AS "41 - 60", 178 | SUM(CASE WHEN a.age_bucket = '61 and Above' Then 1 Else 0 END) AS "61+" 179 | FROM customer_details AS a 180 | INNER JOIN customer_preference AS b 181 | ON a.consumer_id = b.consumer_id 182 | GROUP BY b.preferred_cuisine 183 | ORDER BY b.preferred_cuisine --------------------------------------------------------------------------------