mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-12-02 04:22:03 +00:00
67c2e50331
* update presentations * CLICKHOUSE-2936: redirect from clickhouse.yandex.ru and clickhouse.yandex.com * update submodule * lost files * CLICKHOUSE-2981: prefer sphinx docs over original reference * CLICKHOUSE-2981: docs styles more similar to main website + add flags to switch language links * update presentations * Less confusing directory structure (docs -> doc/reference/) * Minify sphinx docs too * Website release script: fail fast + pass docker hash on deploy * Do not underline links in docs * shorter * cleanup docker images * tune nginx config * CLICKHOUSE-3043: get rid of habrastorage links * Lost translation * CLICKHOUSE-2936: temporary client-side redirect * behaves weird in test * put redirect back * CLICKHOUSE-3047: copy docs txts to public too * move to proper file * remove old pages to avoid confusion * Remove reference redirect warning for now * Refresh README.md * Yellow buttons in docs * Use svg flags instead of unicode ones in docs * fix test website instance * Put flags to separate files * wrong flag * Copy Yandex.Metrica introduction from main page to docs * Yet another home page structure change, couple new blocks (CLICKHOUSE-3045) * Update Contacts section * CLICKHOUSE-2849: more detailed legal information * CLICKHOUSE-2978 preparation - split by files * More changes in Contacts block * Tune texts on index page * update presentations * One more benchmark * Add usage sections to index page, adapted from slides * Get the roadmap started, based on slides from last ClickHouse Meetup * CLICKHOUSE-2977: some rendering tuning * Get rid of excessive section in the end of getting started * Make headers linkable * CLICKHOUSE-2981: links to editing reference - https://github.com/yandex/ClickHouse/issues/849 * CLICKHOUSE-2981: fix mobile styles in docs * Ban crawling of duplicating docs * Open some external links in new tab * Ban old docs too * Lots of trivial fixes in english docs * Lots of trivial fixes in russian docs * Remove getting started copies in markdown * Add Yandex.Webmaster * Fix some sphinx warnings * More warnings fixed in english docs * More sphinx warnings fixed * Add code-block:: text * More code-block:: text * These headers look not that well * Better switch between documentation languages * merge use_case.rst into ya_metrika_task.rst * Edit the agg_functions.rst texts * Add lost empty lines * Lost blank lines * Add new logo sizes * update presentations * Next step in migrating to new documentation * Fix all warnings in en reference * Fix all warnings in ru reference * Re-arrange existing reference * Move operation tips to main reference * Fix typos noticed by milovidov@ * Get rid of zookeeper.md * Looks like duplicate of tutorial.html * Fix some mess with html tags in tutorial * No idea why nobody noticed this before, but it was completely not clear whet to get the data * Match code block styling between main and tutorial pages (in favor of the latter) * Get rid of some copypaste in tutorial * Normalize header styles * Move example_datasets to sphinx * Move presentations submodule to website * Move and update README.md * No point in duplicating articles from habrahabr here * Move development-related docs as is for now * doc/reference/ -> docs/ (to match the URL on website) * Adapt links to match the previous commit * Adapt development docs to rst (still lacks translation and strikethrough support) * clean on release * blacklist presentations in gulp * strikethrough support in sphinx * just copy development folder for now * fix weird introduction in style article * Style guide translation (WIP) * Finish style guide translation to English * gulp clean separately * Update year in LICENSE * Initial CONTRIBUTING.md * Fix remaining links to old docs in tutorial * Some tutorial fixes * Typo * Another typo * Update list of authors from yandex-team accoding to git log
319 lines
8.6 KiB
ReStructuredText
319 lines
8.6 KiB
ReStructuredText
OnTime
|
|
======
|
|
|
|
This benchmark was created by Vadim Tkachenko, see:
|
|
|
|
* 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
|
|
|
|
Download the data:
|
|
|
|
.. code-block:: bash
|
|
|
|
for s in `seq 1987 2017`
|
|
do
|
|
for m in `seq 1 12`
|
|
do
|
|
wget http://transtats.bts.gov/PREZIP/On_Time_On_Time_Performance_${s}_${m}.zip
|
|
done
|
|
done
|
|
|
|
(from https://github.com/Percona-Lab/ontime-airline-performance/blob/master/download.sh )
|
|
|
|
Create table:
|
|
|
|
.. code-block:: 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(FlightDate, (Year, FlightDate), 8192)
|
|
|
|
Load the data:
|
|
|
|
.. code-block:: 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
|
|
|
|
Queries:
|
|
|
|
|
|
Q0.
|
|
|
|
.. code-block:: sql
|
|
|
|
select avg(c1) from (select Year, Month, count(*) as c1 from ontime group by Year, Month);
|
|
|
|
Q1. Count flights per day from 2000 to 2008 years
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT DayOfWeek, count(*) AS c FROM ontime WHERE Year >= 2000 AND Year <= 2008 GROUP BY DayOfWeek ORDER BY c DESC;
|
|
|
|
Q2. Count of flights delayed more than 10min per day of week for 2000-2008 years
|
|
|
|
.. code-block:: 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. Count of delays per airport for years 2000-2008
|
|
|
|
.. code-block:: 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. Count of delays per Carrier for 2007 year
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Carrier, count(*) FROM ontime WHERE DepDelay>10 AND Year = 2007 GROUP BY Carrier ORDER BY count(*) DESC
|
|
|
|
Q5. Percentage of delays for each carrier for 2007 year.
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Carrier, c, c2, c*1000/c2 as c3
|
|
FROM
|
|
(
|
|
SELECT
|
|
Carrier,
|
|
count(*) AS c
|
|
FROM ontime
|
|
WHERE DepDelay>10
|
|
AND Year=2007
|
|
GROUP BY Carrier
|
|
)
|
|
ANY INNER JOIN
|
|
(
|
|
SELECT
|
|
Carrier,
|
|
count(*) AS c2
|
|
FROM ontime
|
|
WHERE Year=2007
|
|
GROUP BY Carrier
|
|
) USING Carrier
|
|
ORDER BY c3 DESC;
|
|
|
|
More optimal version of same query:
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Carrier, avg(DepDelay > 10) * 1000 AS c3 FROM ontime WHERE Year = 2007 GROUP BY Carrier ORDER BY Carrier
|
|
|
|
Q6. Let's try the same query for wide range of years 2000-2008.
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Carrier, c, c2, c*1000/c2 as c3
|
|
FROM
|
|
(
|
|
SELECT
|
|
Carrier,
|
|
count(*) AS c
|
|
FROM ontime
|
|
WHERE DepDelay>10
|
|
AND Year >= 2000 AND Year <= 2008
|
|
GROUP BY Carrier
|
|
)
|
|
ANY INNER JOIN
|
|
(
|
|
SELECT
|
|
Carrier,
|
|
count(*) AS c2
|
|
FROM ontime
|
|
WHERE Year >= 2000 AND Year <= 2008
|
|
GROUP BY Carrier
|
|
) USING Carrier
|
|
ORDER BY c3 DESC;
|
|
|
|
More optimal version of same query:
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Carrier, avg(DepDelay > 10) * 1000 AS c3 FROM ontime WHERE Year >= 2000 AND Year <= 2008 GROUP BY Carrier ORDER BY Carrier
|
|
|
|
Q7. Percent of delayed (more 10mins) flights per year.
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Year, c1/c2
|
|
FROM
|
|
(
|
|
select
|
|
Year,
|
|
count(*)*1000 as c1
|
|
from ontime
|
|
WHERE DepDelay>10
|
|
GROUP BY Year
|
|
)
|
|
ANY INNER JOIN
|
|
(
|
|
select
|
|
Year,
|
|
count(*) as c2
|
|
from ontime
|
|
GROUP BY Year
|
|
) USING (Year)
|
|
ORDER BY Year
|
|
|
|
More optimal version of same query:
|
|
|
|
.. code-block:: sql
|
|
|
|
SELECT Year, avg(DepDelay > 10) FROM ontime GROUP BY Year ORDER BY Year
|
|
|
|
Q8. Most popular destination in sense count of direct connected cities for different range of years.
|
|
|
|
.. code-block:: 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.
|
|
|
|
.. code-block:: sql
|
|
|
|
select Year, count(*) as c1 from ontime group by Year;
|
|
|
|
Q10.
|
|
|
|
.. code-block:: 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;
|
|
|
|
Bonus:
|
|
|
|
.. code-block:: 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;
|