Parquet SerDe
SerDe name
ParquetHiveSerDe is used for data stored in Parquet
format
To convert data into Parquet format, you can use CREATE TABLE AS SELECT (CTAS) queries. For more information, see Creating a table from query results (CTAS), Examples of CTAS queries and Using CTAS and INSERT INTO for ETL and data analysis.
Library name
Athena uses the following class when it needs to deserialize data stored in Parquet: org.apache.hadoop.hive.ql.io.parquet.serde.ParquetHiveSerDe
Example: Querying a file stored in parquet
Replace myregion
in s3://athena-examples-
with the region identifier where you run Athena, for example, myregion
/path/to/data/s3://athena-examples-us-west-1/path/to/data/
.
Use the following CREATE TABLE
statement to
create an Athena table from the underlying data in CSV stored in Amazon S3 in Parquet:
CREATE EXTERNAL TABLE flight_delays_pq ( yr INT, quarter INT, month INT, dayofmonth INT, dayofweek INT, flightdate STRING, uniquecarrier STRING, airlineid INT, carrier STRING, tailnum STRING, flightnum STRING, originairportid INT, originairportseqid INT, origincitymarketid INT, origin STRING, origincityname STRING, originstate STRING, originstatefips STRING, originstatename STRING, originwac INT, destairportid INT, destairportseqid INT, destcitymarketid INT, dest STRING, destcityname STRING, deststate STRING, deststatefips STRING, deststatename STRING, destwac INT, crsdeptime STRING, deptime STRING, depdelay INT, depdelayminutes INT, depdel15 INT, departuredelaygroups INT, deptimeblk STRING, taxiout INT, wheelsoff STRING, wheelson STRING, taxiin INT, crsarrtime INT, arrtime STRING, arrdelay INT, arrdelayminutes INT, arrdel15 INT, arrivaldelaygroups INT, arrtimeblk STRING, cancelled INT, cancellationcode STRING, diverted INT, crselapsedtime INT, actualelapsedtime INT, airtime INT, flights INT, distance INT, distancegroup INT, carrierdelay INT, weatherdelay INT, nasdelay INT, securitydelay INT, lateaircraftdelay INT, firstdeptime STRING, totaladdgtime INT, longestaddgtime INT, divairportlandings INT, divreacheddest INT, divactualelapsedtime INT, divarrdelay INT, divdistance INT, div1airport STRING, div1airportid INT, div1airportseqid INT, div1wheelson STRING, div1totalgtime INT, div1longestgtime INT, div1wheelsoff STRING, div1tailnum STRING, div2airport STRING, div2airportid INT, div2airportseqid INT, div2wheelson STRING, div2totalgtime INT, div2longestgtime INT, div2wheelsoff STRING, div2tailnum STRING, div3airport STRING, div3airportid INT, div3airportseqid INT, div3wheelson STRING, div3totalgtime INT, div3longestgtime INT, div3wheelsoff STRING, div3tailnum STRING, div4airport STRING, div4airportid INT, div4airportseqid INT, div4wheelson STRING, div4totalgtime INT, div4longestgtime INT, div4wheelsoff STRING, div4tailnum STRING, div5airport STRING, div5airportid INT, div5airportseqid INT, div5wheelson STRING, div5totalgtime INT, div5longestgtime INT, div5wheelsoff STRING, div5tailnum STRING ) PARTITIONED BY (year STRING) STORED AS PARQUET LOCATION 's3://athena-examples-
myregion
/flight/parquet/' tblproperties ("parquet.compression"="SNAPPY");
Run the MSCK REPAIR TABLE
statement on the table to refresh partition
metadata:
MSCK REPAIR TABLE flight_delays_pq;
Query the top 10 routes delayed by more than 1 hour:
SELECT origin, dest, count(*) as delays FROM flight_delays_pq WHERE depdelayminutes > 60 GROUP BY origin, dest ORDER BY 3 DESC LIMIT 10;
The flight table data comes from Flights