mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-25 09:02:00 +00:00
406 lines
8.4 KiB
Markdown
406 lines
8.4 KiB
Markdown
|
||
# 航班飞行数据 {#hang-ban-fei-xing-shu-ju}
|
||
|
||
航班飞行数据有以下两个方式获取:
|
||
|
||
- 从原始数据导入
|
||
- 下载预处理好的分区数据
|
||
|
||
## 从原始数据导入 {#cong-yuan-shi-shu-ju-dao-ru}
|
||
|
||
下载数据:
|
||
|
||
``` bash
|
||
for s in `seq 1987 2018`
|
||
do
|
||
for m in `seq 1 12`
|
||
do
|
||
wget https://transtats.bts.gov/PREZIP/On_Time_Reporting_Carrier_On_Time_Performance_1987_present_${s}_${m}.zip
|
||
done
|
||
done
|
||
```
|
||
|
||
(引用 https://github.com/Percona-Lab/ontime-airline-performance/blob/master/download.sh )
|
||
|
||
创建表结构:
|
||
|
||
``` sql
|
||
CREATE TABLE `ontime` (
|
||
`Year` UInt16,
|
||
`Quarter` UInt8,
|
||
`Month` UInt8,
|
||
`DayofMonth` UInt8,
|
||
`DayOfWeek` UInt8,
|
||
`FlightDate` Date,
|
||
`UniqueCarrier` FixedString(7),
|
||
`AirlineID` Int32,
|
||
`Carrier` FixedString(2),
|
||
`TailNum` String,
|
||
`FlightNum` String,
|
||
`OriginAirportID` Int32,
|
||
`OriginAirportSeqID` Int32,
|
||
`OriginCityMarketID` Int32,
|
||
`Origin` FixedString(5),
|
||
`OriginCityName` String,
|
||
`OriginState` FixedString(2),
|
||
`OriginStateFips` String,
|
||
`OriginStateName` String,
|
||
`OriginWac` Int32,
|
||
`DestAirportID` Int32,
|
||
`DestAirportSeqID` Int32,
|
||
`DestCityMarketID` Int32,
|
||
`Dest` FixedString(5),
|
||
`DestCityName` String,
|
||
`DestState` FixedString(2),
|
||
`DestStateFips` String,
|
||
`DestStateName` String,
|
||
`DestWac` Int32,
|
||
`CRSDepTime` Int32,
|
||
`DepTime` Int32,
|
||
`DepDelay` Int32,
|
||
`DepDelayMinutes` Int32,
|
||
`DepDel15` Int32,
|
||
`DepartureDelayGroups` String,
|
||
`DepTimeBlk` String,
|
||
`TaxiOut` Int32,
|
||
`WheelsOff` Int32,
|
||
`WheelsOn` Int32,
|
||
`TaxiIn` Int32,
|
||
`CRSArrTime` Int32,
|
||
`ArrTime` Int32,
|
||
`ArrDelay` Int32,
|
||
`ArrDelayMinutes` Int32,
|
||
`ArrDel15` Int32,
|
||
`ArrivalDelayGroups` Int32,
|
||
`ArrTimeBlk` String,
|
||
`Cancelled` UInt8,
|
||
`CancellationCode` FixedString(1),
|
||
`Diverted` UInt8,
|
||
`CRSElapsedTime` Int32,
|
||
`ActualElapsedTime` Int32,
|
||
`AirTime` Int32,
|
||
`Flights` Int32,
|
||
`Distance` Int32,
|
||
`DistanceGroup` UInt8,
|
||
`CarrierDelay` Int32,
|
||
`WeatherDelay` Int32,
|
||
`NASDelay` Int32,
|
||
`SecurityDelay` Int32,
|
||
`LateAircraftDelay` Int32,
|
||
`FirstDepTime` String,
|
||
`TotalAddGTime` String,
|
||
`LongestAddGTime` String,
|
||
`DivAirportLandings` String,
|
||
`DivReachedDest` String,
|
||
`DivActualElapsedTime` String,
|
||
`DivArrDelay` String,
|
||
`DivDistance` String,
|
||
`Div1Airport` String,
|
||
`Div1AirportID` Int32,
|
||
`Div1AirportSeqID` Int32,
|
||
`Div1WheelsOn` String,
|
||
`Div1TotalGTime` String,
|
||
`Div1LongestGTime` String,
|
||
`Div1WheelsOff` String,
|
||
`Div1TailNum` String,
|
||
`Div2Airport` String,
|
||
`Div2AirportID` Int32,
|
||
`Div2AirportSeqID` Int32,
|
||
`Div2WheelsOn` String,
|
||
`Div2TotalGTime` String,
|
||
`Div2LongestGTime` String,
|
||
`Div2WheelsOff` String,
|
||
`Div2TailNum` String,
|
||
`Div3Airport` String,
|
||
`Div3AirportID` Int32,
|
||
`Div3AirportSeqID` Int32,
|
||
`Div3WheelsOn` String,
|
||
`Div3TotalGTime` String,
|
||
`Div3LongestGTime` String,
|
||
`Div3WheelsOff` String,
|
||
`Div3TailNum` String,
|
||
`Div4Airport` String,
|
||
`Div4AirportID` Int32,
|
||
`Div4AirportSeqID` Int32,
|
||
`Div4WheelsOn` String,
|
||
`Div4TotalGTime` String,
|
||
`Div4LongestGTime` String,
|
||
`Div4WheelsOff` String,
|
||
`Div4TailNum` String,
|
||
`Div5Airport` String,
|
||
`Div5AirportID` Int32,
|
||
`Div5AirportSeqID` Int32,
|
||
`Div5WheelsOn` String,
|
||
`Div5TotalGTime` String,
|
||
`Div5LongestGTime` String,
|
||
`Div5WheelsOff` String,
|
||
`Div5TailNum` String
|
||
) ENGINE = MergeTree
|
||
PARTITION BY Year
|
||
ORDER BY (Carrier, FlightDate)
|
||
SETTINGS index_granularity = 8192;
|
||
```
|
||
|
||
加载数据:
|
||
|
||
``` bash
|
||
$ for i in *.zip; do echo $i; unzip -cq $i '*.csv' | sed 's/\.00//g' | clickhouse-client --host=example-perftest01j --query="INSERT INTO ontime FORMAT CSVWithNames"; done
|
||
```
|
||
|
||
## 下载预处理好的分区数据 {#xia-zai-yu-chu-li-hao-de-fen-qu-shu-ju}
|
||
|
||
``` bash
|
||
$ curl -O https://clickhouse-datasets.s3.yandex.net/ontime/partitions/ontime.tar
|
||
$ tar xvf ontime.tar -C /var/lib/clickhouse # path to ClickHouse data directory
|
||
$ # check permissions of unpacked data, fix if required
|
||
$ sudo service clickhouse-server restart
|
||
$ clickhouse-client --query "select count(*) from datasets.ontime"
|
||
```
|
||
|
||
!!! info "信息"
|
||
如果要运行下面的SQL查询,必须使用完整的表名,
|
||
`datasets.ontime`。
|
||
|
||
## 查询: {#cha-xun}
|
||
|
||
Q0.
|
||
|
||
``` sql
|
||
SELECT avg(c1)
|
||
FROM
|
||
(
|
||
SELECT Year, Month, count(*) AS c1
|
||
FROM ontime
|
||
GROUP BY Year, Month
|
||
);
|
||
```
|
||
|
||
Q1. 查询从2000年到2008年每天的航班数
|
||
|
||
``` sql
|
||
SELECT DayOfWeek, count(*) AS c
|
||
FROM ontime
|
||
WHERE Year>=2000 AND Year<=2008
|
||
GROUP BY DayOfWeek
|
||
ORDER BY c DESC;
|
||
```
|
||
|
||
Q2. 查询从2000年到2008年每周延误超过10分钟的航班数。
|
||
|
||
``` sql
|
||
SELECT DayOfWeek, count(*) AS c
|
||
FROM ontime
|
||
WHERE DepDelay>10 AND Year>=2000 AND Year<=2008
|
||
GROUP BY DayOfWeek
|
||
ORDER BY c DESC;
|
||
```
|
||
|
||
Q3. 查询2000年到2008年每个机场延误超过10分钟以上的次数
|
||
|
||
``` sql
|
||
SELECT Origin, count(*) AS c
|
||
FROM ontime
|
||
WHERE DepDelay>10 AND Year>=2000 AND Year<=2008
|
||
GROUP BY Origin
|
||
ORDER BY c DESC
|
||
LIMIT 10;
|
||
```
|
||
|
||
Q4. 查询2007年各航空公司延误超过10分钟以上的次数
|
||
|
||
``` sql
|
||
SELECT Carrier, count(*)
|
||
FROM ontime
|
||
WHERE DepDelay>10 AND Year=2007
|
||
GROUP BY Carrier
|
||
ORDER BY count(*) DESC;
|
||
```
|
||
|
||
Q5. 查询2007年各航空公司延误超过10分钟以上的百分比
|
||
|
||
``` sql
|
||
SELECT Carrier, c, c2, c*100/c2 as c3
|
||
FROM
|
||
(
|
||
SELECT
|
||
Carrier,
|
||
count(*) AS c
|
||
FROM ontime
|
||
WHERE DepDelay>10
|
||
AND Year=2007
|
||
GROUP BY Carrier
|
||
)
|
||
JOIN
|
||
(
|
||
SELECT
|
||
Carrier,
|
||
count(*) AS c2
|
||
FROM ontime
|
||
WHERE Year=2007
|
||
GROUP BY Carrier
|
||
) USING Carrier
|
||
ORDER BY c3 DESC;
|
||
```
|
||
|
||
更好的查询版本:
|
||
|
||
``` sql
|
||
SELECT Carrier, avg(DepDelay>10)*100 AS c3
|
||
FROM ontime
|
||
WHERE Year=2007
|
||
GROUP BY Carrier
|
||
ORDER BY c3 DESC
|
||
```
|
||
|
||
Q6. 同上一个查询一致,只是查询范围扩大到2000年到2008年
|
||
|
||
``` sql
|
||
SELECT Carrier, c, c2, c*100/c2 as c3
|
||
FROM
|
||
(
|
||
SELECT
|
||
Carrier,
|
||
count(*) AS c
|
||
FROM ontime
|
||
WHERE DepDelay>10
|
||
AND Year>=2000 AND Year<=2008
|
||
GROUP BY Carrier
|
||
)
|
||
JOIN
|
||
(
|
||
SELECT
|
||
Carrier,
|
||
count(*) AS c2
|
||
FROM ontime
|
||
WHERE Year>=2000 AND Year<=2008
|
||
GROUP BY Carrier
|
||
) USING Carrier
|
||
ORDER BY c3 DESC;
|
||
```
|
||
|
||
更好的查询版本:
|
||
|
||
``` sql
|
||
SELECT Carrier, avg(DepDelay>10)*100 AS c3
|
||
FROM ontime
|
||
WHERE Year>=2000 AND Year<=2008
|
||
GROUP BY Carrier
|
||
ORDER BY c3 DESC;
|
||
```
|
||
|
||
Q7. 每年航班延误超过10分钟的百分比
|
||
|
||
``` sql
|
||
SELECT Year, c1/c2
|
||
FROM
|
||
(
|
||
select
|
||
Year,
|
||
count(*)*100 as c1
|
||
from ontime
|
||
WHERE DepDelay>10
|
||
GROUP BY Year
|
||
)
|
||
JOIN
|
||
(
|
||
select
|
||
Year,
|
||
count(*) as c2
|
||
from ontime
|
||
GROUP BY Year
|
||
) USING (Year)
|
||
ORDER BY Year;
|
||
```
|
||
|
||
更好的查询版本:
|
||
|
||
``` sql
|
||
SELECT Year, avg(DepDelay>10)*100
|
||
FROM ontime
|
||
GROUP BY Year
|
||
ORDER BY Year;
|
||
```
|
||
|
||
Q8. 每年更受人们喜爱的目的地
|
||
|
||
``` sql
|
||
SELECT DestCityName, uniqExact(OriginCityName) AS u
|
||
FROM ontime
|
||
WHERE Year >= 2000 and Year <= 2010
|
||
GROUP BY DestCityName
|
||
ORDER BY u DESC LIMIT 10;
|
||
```
|
||
|
||
Q9.
|
||
|
||
``` sql
|
||
SELECT Year, count(*) AS c1
|
||
FROM ontime
|
||
GROUP BY Year;
|
||
```
|
||
|
||
Q10.
|
||
|
||
``` sql
|
||
SELECT
|
||
min(Year), max(Year), Carrier, count(*) AS cnt,
|
||
sum(ArrDelayMinutes>30) AS flights_delayed,
|
||
round(sum(ArrDelayMinutes>30)/count(*),2) AS rate
|
||
FROM ontime
|
||
WHERE
|
||
DayOfWeek NOT IN (6,7) AND OriginState NOT IN ('AK', 'HI', 'PR', 'VI')
|
||
AND DestState NOT IN ('AK', 'HI', 'PR', 'VI')
|
||
AND FlightDate < '2010-01-01'
|
||
GROUP by Carrier
|
||
HAVING cnt>100000 and max(Year)>1990
|
||
ORDER by rate DESC
|
||
LIMIT 1000;
|
||
```
|
||
|
||
奖金:
|
||
|
||
``` sql
|
||
SELECT avg(cnt)
|
||
FROM
|
||
(
|
||
SELECT Year,Month,count(*) AS cnt
|
||
FROM ontime
|
||
WHERE DepDel15=1
|
||
GROUP BY Year,Month
|
||
);
|
||
|
||
SELECT avg(c1) FROM
|
||
(
|
||
SELECT Year,Month,count(*) AS c1
|
||
FROM ontime
|
||
GROUP BY Year,Month
|
||
);
|
||
|
||
SELECT DestCityName, uniqExact(OriginCityName) AS u
|
||
FROM ontime
|
||
GROUP BY DestCityName
|
||
ORDER BY u DESC
|
||
LIMIT 10;
|
||
|
||
SELECT OriginCityName, DestCityName, count() AS c
|
||
FROM ontime
|
||
GROUP BY OriginCityName, DestCityName
|
||
ORDER BY c DESC
|
||
LIMIT 10;
|
||
|
||
SELECT OriginCityName, count() AS c
|
||
FROM ontime
|
||
GROUP BY OriginCityName
|
||
ORDER BY c DESC
|
||
LIMIT 10;
|
||
```
|
||
|
||
这个性能测试由Vadim Tkachenko提供。参考:
|
||
|
||
- https://www.percona.com/blog/2009/10/02/analyzing-air-traffic-performance-with-infobright-and-monetdb/
|
||
- https://www.percona.com/blog/2009/10/26/air-traffic-queries-in-luciddb/
|
||
- https://www.percona.com/blog/2009/11/02/air-traffic-queries-in-infinidb-early-alpha/
|
||
- https://www.percona.com/blog/2014/04/21/using-apache-hadoop-and-impala-together-with-mysql-for-data-analysis/
|
||
- https://www.percona.com/blog/2016/01/07/apache-spark-with-air-ontime-performance-data/
|
||
- http://nickmakos.blogspot.ru/2012/08/analyzing-air-traffic-performance-with.html
|