本笔记为阿里云天池龙珠计划SQL训练营的学习内容
练习题1:
数据来源:https://tianchi.aliyun.com/dataset/dataDetail?dataId=1074
请使用A股上市公司季度营收预测数据集《Income Statement.xls》和《Company Operating.xlsx》和《Market Data.xlsx》,以Market Data为主表,将三张表中的TICKER_SYMBOL为600383和600048的信息合并在一起。只需要显示以下字段。
表名 | 字段名 |
Income Statement | TICKER_SYMBOL |
Income Statement | END_DATE |
Income Statement | T_REVENUE |
Income Statement | T_COGS |
Income Statement | N_INCOME |
Market Data | TICKER_SYMBOL |
Market Data | END_DATE_ |
Market Data | CLOSE_PRICE |
Company Operating | TICKER_SYMBOL |
Company Operating | INDIC_NAME_EN |
Company Operating | END_DATE |
Company Operating | VALUE |
SELECT A.TICKER_SYMBOL, A.END_DATE,A.T_REVENUE,A.T_COGS,A.N_INCOME,
B.CLOSE_PRICE,C.INDIC_NAME_EN,C.`VALUE`
FROM `income statement` AS A INNER JOIN `market data` AS B
ON A.TICKER_SYMBOL = B.TICKER_SYMBOL AND A.END_DATE = B.END_DATE
INNER JOIN `company operating` AS C
ON A.TICKER_SYMBOL = C.TICKER_SYMBOL AND A.END_DATE = C.END_DATE
WHERE A.TICKER_SYMBOL IN (600383,600048);
练习题2:
数据来源:https://tianchi.aliyun.com/dataset/dataDetail?dataId=44
请使用 Wine Quality Data 数据集《winequality-red.csv》,找出 pH=3.03的所有红葡萄酒,然后,对其 citric acid 进行中式排名(相同排名的下一个名次应该是下一个连续的整数值。换句话说,名次之间不应该有“间隔”)
select *,dense_rank() over (order by `citric acid`)
FROM `winequality-red`
WHERE pH = 3.03;
练习题3:
数据来源:https://tianchi.aliyun.com/competition/entrance/231593/information
使用Coupon Usage Data for O2O中的数据集《ccf_offline_stage1_test_revised.csv》,试分别找出在2016年7月期间,发放优惠券总金额最多和发放优惠券张数最多的商家。
这里只考虑满减的金额,不考虑打几折的优惠券。
SELECT SUM(Discount_rate),Merchant_id
FROM ccf_offline_stage1_test_revised
GROUP BY Merchant_id
ORDER BY SUM(Discount_rate) DESC
LIMIT 1;
SELECT Merchant_id
FROM ccf_offline_stage1_test_revised
GROUP BY Merchant_id
ORDER BY COUNT(Coupon_id) DESC
LIMIT 1;
练习题4:
数据来源:https://tianchi.aliyun.com/dataset/dataDetail?dataId=1074
请使用A股上市公司季度营收预测中的数据集《Macro&Industry.xlsx》中的sheet-INDIC_DATA,请计算全社会用电量:第一产业:当月值在2015年用电最高峰是发生在哪月?并且相比去年同期增长/减少了多少个百分比?
SELECT PERIOD_DATE FROM `macro industry`
WHERE YEAR(PERIOD_DATE)="2015" AND indic_id = "2020101522"
GROUP BY PERIOD_DATE ORDER BY MAX(DATA_VALUE) DESC
LIMIT 1;
SELECT ROUND((any_value(m2.val)-max(m1.DATA_VALUE))/max(m1.DATA_VALUE),2) compare_rate FROM `macro industry` m1,
(
SELECT PERIOD_DATE,max(DATA_VALUE)val FROM `macro industry` mi
WHERE YEAR(PERIOD_DATE) ="2015" AND indic_id = "2020101522"
GROUP BY PERIOD_DATE ORDER BY max(DATA_VALUE) DESC LIMIT 1
)m2
WHERE YEAR(m1.PERIOD_DATE) ="2014" AND m1.indic_id = "2020101522" AND MONTH(m1.PERIOD_DATE) = MONTH(m2.PERIOD_DATE) GROUP BY m1.PERIOD_DATE ORDER BY max(m1.DATA_VALUE) DESC LIMIT 1;
练习题5:
数据来源:https://tianchi.aliyun.com/competition/entrance/231593/information
使用Coupon Usage Data for O2O中的数据集《ccf_online_stage1_train.csv》,试统计在2016年6月期间,线上总体优惠券弃用率为多少?并找出优惠券弃用率最高的商家。
弃用率 = 被领券但未使用的优惠券张数 / 总的被领取优惠券张数
SELECT SUM(CASE WHEN Date is NULL AND Coupon_id IS NOT NULL
THEN 1 ELSE 0 END) /SUM(CASE WHEN Coupon_id IS NOT NULL
THEN 1 ELSE 0 END) AS discard_rate FROM ccf_online_stage1_train
WHERE Date_received BETWEEN '2016-06-01' AND '2016-06-30';
SELECT Merchant_id ,SUM(CASE WHEN Date is NULL AND Coupon_id IS NOT NULL
THEN 1 ELSE 0 END) /SUM(CASE WHEN Coupon_id IS NOT NULL THEN 1 ELSE 0 END) AS discard_rate FROM ccf_online_stage1_train
WHERE Date_received BETWEEN '2016-06-01' AND '2016-06-30'
GROUP BY Merchant_id ORDER BY discard_rate DESC LIMIT 1;
练习题6:
数据来源:https://tianchi.aliyun.com/dataset/dataDetail?dataId=44
请使用 Wine Quality Data 数据集《winequality-white.csv》,找出 pH=3.63的所有白葡萄酒,然后,对其 residual sugar 量进行英式排名(非连续的排名)
SELECT *,RANK() over(order by `residual sugar`)
FROM `winequality-white`
WHERE pH=3.63;
练习题7:
数据来源:https://tianchi.aliyun.com/dataset/dataDetail?dataId=1074
请使用A股上市公司季度营收预测中的数据集《Market Data.xlsx》中的sheet-DATA,
计算截止到2018年底,市值最大的三个行业是哪些?以及这三个行业里市值最大的三个公司是哪些?(每个行业找出前三大的公司,即一共要找出9个)
SELECT SUM(MARKET_VALUE),TYPE_NAME_CN FROM `market data`
WHERE YEAR(END_DATE) = '2018' GROUP BY TYPE_NAME_CN
ORDER BY SUM(MARKET_VALUE) DESC LIMIT 3;
SELECT m1.TYPE_NAME_CN,m1.TICKER_SYMBOL
FROM (SELECT TYPE_NAME_CN,TICKER_SYMBOL,MARKET_VALUE,
ROW_NUMBER() OVER(PARTITION BY TYPE_NAME_CN ORDER BY MARKET_VALUE) AS CompanyRanking FROM `market data` )m1
LEFT JOIN (SELECT TYPE_NAME_CN,SUM(MARKET_VALUE)
FROM `market data` WHERE YEAR(END_DATE) = '2018'
GROUP BY TYPE_NAME_CN ORDER BY SUM(MARKET_VALUE) DESC
LIMIT 3 ) top3Type ON m1.TYPE_NAME_CN = top3Type.TYPE_NAME_CN
WHERE CompanyRanking <= 3 AND top3Type.TYPE_NAME_CN IS NOT NULL;
练习题8:
数据来源:https://tianchi.aliyun.com/competition/entrance/231593/information
使用Coupon Usage Data for O2O中的数据集《ccf_online_stage1_train.csv》和《ccf_offline_stage1_train.csv》,试找出在2016年6月期间,线上线下累计优惠券使用次数最多的顾客。
SELECT User_id ,SUM(count1.countnumber) number
FROM (SELECT User_id ,COUNT(*) countnumber FROM ccf_offline_stage1_train
WHERE LEFT(Date,6)="201606" AND( Coupon_id is NOT NULL AND Date is not NULL) GROUP BY User_id UNION ALL
SELECT User_id,COUNT(*) countnumber FROM ccf_online_stage1_train
WHERE MONTH(Date) = "06" AND( Coupon_id is NOT NULL AND Date is NOT NULL) GROUP BY User_id )count1
GROUP BY User_id ORDER BY SUM(count1.countnumber) DESC LIMIT 1;
练习题9:
数据来源:https://tianchi.aliyun.com/dataset/dataDetail?dataId=1074
请使用A股上市公司季度营收预测数据集《Income Statement.xls》中的sheet-General Business和《Company Operating.xlsx》中的sheet-EN。
找出在数据集所有年份中,按季度统计,白云机场旅客吞吐量最高的那一季度对应的净利润是多少?(注意,是单季度对应的净利润,非累计净利润。)
SELECT * FROM (SELECT QUARTER(END_DATE) QUARTER,YEAR(END_DATE) Year, TICKER_SYMBOL, SUM(`VALUE`) Throughput FROM `company operating`
WHERE INDIC_NAME_EN = "Baiyun Airport:Aircraft take-off and landing times"
GROUP BY TICKER_SYMBOL,YEAR(END_DATE),QUARTER(END_DATE)
ORDER BY SUM(`VALUE`) LIMIT 1)season
LEFT JOIN (SELECT TICKER_SYMBOL, YEAR(END_DATE) Year, QUARTER(END_DATE) QUARTER, SUM(N_INCOME) net_profit FROM `income statement`
GROUP BY TICKER_SYMBOL,YEAR(END_DATE),QUARTER(END_DATE) ) Income
ON season.TICKER_SYMBOL = Income.TICKER_SYMBOL
AND season.Year = Income.Year AND season.QUARTER = Income.QUARTER;
练习题10:
数据来源:https://tianchi.aliyun.com/competition/entrance/231593/information
使用Coupon Usage Data for O2O中的数据集《ccf_online_stage1_train.csv》和《ccf_offline_stage1_train.csv》,试找出在2016年6月期间,线上线下累计被使用优惠券满减最多的前3名商家。
比如商家A,消费者A在其中使用了一张200减50的,消费者B使用了一张30减1的,那么商家A累计被使用优惠券满减51元。
SELECT Merchant_id ,SUM(number) number
FROM ( SELECT Merchant_id ,SUM(SUBSTRING_INDEX(`Discount_rate`,':',-1)) number
FROM ccf_online_stage1_train WHERE LEFT(Date,6)="201606" AND( Coupon_id is NOT NULL AND Date is NOT NULL)
GROUP BY Merchant_id UNION ALL
SELECT Merchant_id ,SUM(SUBSTRING_INDEX(`Discount_rate`,':',-1)) number
FROM ccf_offline_stage1_train WHERE LEFT(Date,6)="201606" AND( Coupon_id is NOT NULL AND Date is not NULL) GROUP BY Merchant_id )count1
GROUP BY Merchant_id ORDER BY SUM(number) DESC LIMIT 3;