用于 CSV、TSV 和自定义分隔文件的 Lazy Simple SerDe
因为这是 Athena 中用于 CSV、TSV 和自定义分隔格式的数据的默认 SerDe,所以指定它是可选的。在您的 CREATE TABLE
语句中,如果您没有指定 SerDe 而只是指定 ROW FORMAT DELIMITED
,Athena 就会使用此 SerDe。如果您的数据没有用引号引起来的值,请使用此 SerDe。
有关 Lazy Simple SerDe 的参考文档,请参阅《Apache Hive 开发人员指南》中的 Hive SerDe
序列化库名称
Lazy Simple SerDe 的序列化库名称是 org.apache.hadoop.hive.serde2.lazy.LazySimpleSerDe
。有关源代码的信息,请参阅 GitHub.com 上的 LazySimpleSerDe.java
忽略标题
要在您定义表时忽略标题,可以使用 skip.header.line.count
表属性,如下例所示。
TBLPROPERTIES ("skip.header.line.count"="1")
有关忽略标头的示例,请参阅 查询 Amazon VPC 流日志 和 查询 Amazon CloudFront 日志 中的 CREATE TABLE
语句。
以下示例显示如何使用 LazySimpleSerDe
库根据 CSV 数据在 Athena 中创建表。要使用此 SerDe 反序列化自定义分隔的文件,请遵循示例中的模式,但使用 FIELDS TERMINATED
BY
子句指定单字符分隔符。Lazy Simple SerDe 不支持多字符分隔符。
使用 CREATE TABLE
语句根据在 Amazon S3 中存储的底层 CSV 数据创建一个 Athena 表。
CREATE EXTERNAL TABLE flight_delays_csv ( 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) ROW FORMAT DELIMITED FIELDS TERMINATED BY ',' ESCAPED BY '\\' LINES TERMINATED BY '\n' LOCATION 's3://athena-examples-
myregion
/flight/csv/';
每次将新分区添加到此表时,请运行 MSCK REPAIR TABLE
以刷新分区元数据:
MSCK REPAIR TABLE flight_delays_csv;
查询前 10 个延迟超过 1 小时的路线:
SELECT origin, dest, count(*) as delays FROM flight_delays_csv WHERE depdelayminutes > 60 GROUP BY origin, dest ORDER BY 3 DESC LIMIT 10;
要根据存储在 Amazon S3 中的 TSV 数据创建 Athena 表,请使用 ROW FORMAT
DELIMITED
并指定 \t
为制表符字段分隔符,指定 \n
为行分隔符,指定 \
为转义字符。以下示例显示该语法。athena-examples
地点没有示例 TSV 传输数据,但与 CSV 表一样,每次添加新分区时,您都需要运行 MSCK REPAIR TABLE
刷新分区元数据。
... ROW FORMAT DELIMITED FIELDS TERMINATED BY '\t' ESCAPED BY '\\' LINES TERMINATED BY '\n' ...