Skip to content

Commit 8ce3244

Browse files
authored
Update #4 Finance analysis.sql
1 parent 8b4e13a commit 8ce3244

File tree

1 file changed

+186
-0
lines changed

1 file changed

+186
-0
lines changed

RAW SQL/#4 Finance analysis.sql

Lines changed: 186 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1 +1,187 @@
1+
/*Date created and Last ran in MySQL: 09-12-2023
2+
Challenge 4 - Finance Analysis
3+
Challenge Source: https://steeldata.org.uk/sql4.html */
4+
5+
CREATE DATABASE STEEL_DATA;
6+
USE STEEL_DATA;
7+
8+
-- Create the Customers table
9+
CREATE TABLE Customers (
10+
CustomerID INT PRIMARY KEY,
11+
FirstName VARCHAR(50) NOT NULL,
12+
LastName VARCHAR(50) NOT NULL,
13+
City VARCHAR(50) NOT NULL,
14+
State VARCHAR(2) NOT NULL
15+
);
16+
--------------------
17+
-- Populate the Customers table
18+
INSERT INTO Customers (CustomerID, FirstName, LastName, City, State)
19+
VALUES (1, 'John', 'Doe', 'New York', 'NY'),
20+
(2, 'Jane', 'Doe', 'New York', 'NY'),
21+
(3, 'Bob', 'Smith', 'San Francisco', 'CA'),
22+
(4, 'Alice', 'Johnson', 'San Francisco', 'CA'),
23+
(5, 'Michael', 'Lee', 'Los Angeles', 'CA'),
24+
(6, 'Jennifer', 'Wang', 'Los Angeles', 'CA');
25+
--------------------
26+
-- Create the Branches table
27+
CREATE TABLE Branches (
28+
BranchID INT PRIMARY KEY,
29+
BranchName VARCHAR(50) NOT NULL,
30+
City VARCHAR(50) NOT NULL,
31+
State VARCHAR(2) NOT NULL
32+
);
33+
--------------------
34+
-- Populate the Branches table
35+
INSERT INTO Branches (BranchID, BranchName, City, State)
36+
VALUES (1, 'Main', 'New York', 'NY'),
37+
(2, 'Downtown', 'San Francisco', 'CA'),
38+
(3, 'West LA', 'Los Angeles', 'CA'),
39+
(4, 'East LA', 'Los Angeles', 'CA'),
40+
(5, 'Uptown', 'New York', 'NY'),
41+
(6, 'Financial District', 'San Francisco', 'CA'),
42+
(7, 'Midtown', 'New York', 'NY'),
43+
(8, 'South Bay', 'San Francisco', 'CA'),
44+
(9, 'Downtown', 'Los Angeles', 'CA'),
45+
(10, 'Chinatown', 'New York', 'NY'),
46+
(11, 'Marina', 'San Francisco', 'CA'),
47+
(12, 'Beverly Hills', 'Los Angeles', 'CA'),
48+
(13, 'Brooklyn', 'New York', 'NY'),
49+
(14, 'North Beach', 'San Francisco', 'CA'),
50+
(15, 'Pasadena', 'Los Angeles', 'CA');
51+
--------------------
52+
-- Create the Accounts table
53+
CREATE TABLE Accounts (
54+
AccountID INT PRIMARY KEY,
55+
CustomerID INT NOT NULL,
56+
BranchID INT NOT NULL,
57+
AccountType VARCHAR(50) NOT NULL,
58+
Balance DECIMAL(10, 2) NOT NULL,
59+
FOREIGN KEY (CustomerID) REFERENCES Customers(CustomerID),
60+
FOREIGN KEY (BranchID) REFERENCES Branches(BranchID)
61+
);
62+
--------------------
63+
-- Populate the Accounts table
64+
INSERT INTO Accounts (AccountID, CustomerID, BranchID, AccountType, Balance)
65+
VALUES (1, 1, 5, 'Checking', 1000.00),
66+
(2, 1, 5, 'Savings', 5000.00),
67+
(3, 2, 1, 'Checking', 2500.00),
68+
(4, 2, 1, 'Savings', 10000.00),
69+
(5, 3, 2, 'Checking', 7500.00),
70+
(6, 3, 2, 'Savings', 15000.00),
71+
(7, 4, 8, 'Checking', 5000.00),
72+
(8, 4, 8, 'Savings', 20000.00),
73+
(9, 5, 14, 'Checking', 10000.00),
74+
(10, 5, 14, 'Savings', 50000.00),
75+
(11, 6, 2, 'Checking', 5000.00),
76+
(12, 6, 2, 'Savings', 10000.00),
77+
(13, 1, 5, 'Credit Card', -500.00),
78+
(14, 2, 1, 'Credit Card', -1000.00),
79+
(15, 3, 2, 'Credit Card', -2000.00);
80+
--------------------
81+
-- Create the Transactions table
82+
CREATE TABLE Transactions (
83+
TransactionID INT PRIMARY KEY,
84+
AccountID INT NOT NULL,
85+
TransactionDate DATE NOT NULL,
86+
Amount DECIMAL(10, 2) NOT NULL,
87+
FOREIGN KEY (AccountID) REFERENCES Accounts(AccountID)
88+
);
89+
--------------------
90+
-- Populate the Transactions table
91+
INSERT INTO Transactions (TransactionID, AccountID, TransactionDate, Amount)
92+
VALUES (1, 1, '2022-01-01', -500.00),
93+
(2, 1, '2022-01-02', -250.00),
94+
(3, 2, '2022-01-03', 1000.00),
95+
(4, 3, '2022-01-04', -1000.00),
96+
(5, 3, '2022-01-05', 500.00),
97+
(6, 4, '2022-01-06', 1000.00),
98+
(7, 4, '2022-01-07', -500.00),
99+
(8, 5, '2022-01-08', -2500.00),
100+
(9, 6, '2022-01-09', 500.00),
101+
(10, 6, '2022-01-10', -1000.00),
102+
(11, 7, '2022-01-11', -500.00),
103+
(12, 7, '2022-01-12', -250.00),
104+
(13, 8, '2022-01-13', 1000.00),
105+
(14, 8, '2022-01-14', -1000.00),
106+
(15, 9, '2022-01-15', 500.00);
107+
108+
-- 1. What are the names of all the customers who live in New York?
109+
110+
SELECT FirstName,
111+
LastName
112+
FROM Customers
113+
WHERE City = 'New York';
114+
115+
-- 2. What is the total number of accounts in the Accounts table?
116+
SELECT COUNT(*) AS TotalAccounts
117+
FROM Accounts;
118+
119+
-- 3. What is the total balance of all checking accounts?
120+
SELECT SUM(Balance) AS TotalCheckingBalance
121+
FROM Accounts
122+
WHERE AccountType = 'Checking';
123+
124+
-- 4. What is the total balance of all accounts associated with customers who live in Los Angeles?
125+
SELECT SUM(Balance) AS TotalBalanceLosAngeles
126+
FROM Accounts
127+
JOIN Customers ON Accounts.CustomerID = Customers.CustomerID
128+
WHERE Customers.City = 'Los Angeles';
129+
130+
-- 5. Which branch has the highest average account balance?
131+
SELECT Branches.BranchName,
132+
ROUND(AVG(Accounts.Balance),2) AS AvgBalance
133+
FROM Branches
134+
JOIN Accounts ON Branches.BranchID = Accounts.BranchID
135+
GROUP BY Branches.BranchName
136+
ORDER BY AvgBalance DESC
137+
LIMIT 1;
138+
-- 6. Which customer has the highest current balance in their accounts?
139+
SELECT Customers.FirstName,
140+
Customers.LastName,
141+
MAX(Accounts.Balance) AS MaxBalance
142+
FROM Customers
143+
JOIN Accounts ON Customers.CustomerID = Accounts.CustomerID
144+
GROUP BY Customers.FirstName, Customers.LastName
145+
ORDER BY MaxBalance DESC
146+
LIMIT 1;
147+
148+
-- 7. Which customer has made the most transactions in the Transactions table?
149+
SELECT Customers.FirstName,
150+
Customers.LastName,
151+
COUNT(Transactions.TransactionID) AS TotalTransactions
152+
FROM Customers
153+
JOIN Accounts ON Customers.CustomerID = Accounts.CustomerID
154+
JOIN Transactions ON Accounts.AccountID = Transactions.AccountID
155+
GROUP BY Customers.FirstName, Customers.LastName
156+
ORDER BY TotalTransactions DESC
157+
LIMIT 1;
158+
159+
-- 8. Which branch has the highest total balance across all of its accounts?
160+
SELECT Branches.BranchName,
161+
SUM(Accounts.Balance) AS TotalBranchBalance
162+
FROM Branches
163+
JOIN Accounts ON Branches.BranchID = Accounts.BranchID
164+
GROUP BY Branches.BranchName
165+
ORDER BY TotalBranchBalance DESC
166+
LIMIT 1;
167+
168+
-- 9. Which customer has the highest total balance across all of their accounts, including savings and checking accounts?
169+
SELECT Customers.FirstName,
170+
Customers.LastName,
171+
SUM(Accounts.Balance) AS TotalBalance
172+
FROM Customers
173+
JOIN Accounts ON Customers.CustomerID = Accounts.CustomerID
174+
GROUP BY Customers.FirstName, Customers.LastName
175+
ORDER BY TotalBalance DESC
176+
LIMIT 1;
177+
178+
-- 10. Which branch has the highest number of transactions in the Transactions table?
179+
SELECT Branches.BranchName,
180+
COUNT(Transactions.TransactionID) AS TotalTransactions
181+
FROM Branches
182+
JOIN Accounts ON Branches.BranchID = Accounts.BranchID
183+
JOIN Transactions ON Accounts.AccountID = Transactions.AccountID
184+
GROUP BY Branches.BranchName
185+
ORDER BY TotalTransactions DESC
186+
LIMIT 1;
1187

0 commit comments

Comments
 (0)