1+ -- 乘客主题
2+
3+ -- (整体) 通勤费用
4+ select ' 整体' deal_type,
5+ count (1 ) as cnt,
6+ sum (deal_money) / 100 as total,
7+ avg (deal_money) / 100 as per
8+ from sztcard
9+ where deal_type in (' 地铁出站' , ' 巴士' )
10+ union all
11+ select deal_type,
12+ count (1 ) as cnt,
13+ sum (deal_money) / 100 as total,
14+ avg (deal_money) / 100 as per
15+ from sztcard
16+ where deal_type in (' 地铁出站' , ' 巴士' )
17+ group by deal_type;
18+
19+ -- 优惠情况
20+ select case when a .distinct_count = 1 then ' 全票'
21+ when a .distinct_count = 0 .95 then ' 9.5 折'
22+ when a .distinct_count >= 0 .9 then ' 9 折'
23+ when a .distinct_count >= 0 .85 then ' 8.5 折'
24+ when a .distinct_count >= 0 .75 then ' 7.5 折'
25+ when a .distinct_count >= 0 .5 then ' 半票'
26+ when a .distinct_count = 0 then ' 免票'
27+ end as distinct_count_range,
28+ sum (cn) as cn
29+ from (
30+ select deal_money / deal_value as distinct_count, count (1 ) as cn
31+ from sztcard
32+ where deal_value > 0
33+ group by deal_money / deal_value
34+ ) as a
35+ group by case when a .distinct_count = 1 then ' 全票'
36+ when a .distinct_count = 0 .95 then ' 9.5 折'
37+ when a .distinct_count >= 0 .9 then ' 9 折'
38+ when a .distinct_count >= 0 .85 then ' 8.5 折'
39+ when a .distinct_count >= 0 .75 then ' 7.5 折'
40+ when a .distinct_count >= 0 .5 then ' 半票'
41+ when a .distinct_count = 0 then ' 免票'
42+ end;
43+
44+ -- (整体) 出行时间分布
45+ select hour(deal_date) as h, count (1 ) as ct
46+ from sztcard
47+ where deal_type in (' 地铁入站' , ' 巴士' )
48+ group by hour(deal_date)
49+ order by h;
50+
51+ -- (地铁) 通勤时间
52+ with tt as (
53+ select * , row_number() over( partition by card_no order by deal_date) as px
54+ from sztcard
55+ where deal_type rlike ' 地铁'
56+ ),
57+ tt2 as (
58+ select t1 .card_no ,
59+ t1 .deal_type as in_type, t1 .company_name as in_company, t1 .station as in_station, t1 .deal_date as in_date,
60+ t2 .deal_type as out_type, t2 .company_name as out_company, t2 .station as out_station, t2 .deal_date as out_date,
61+ unix_timestamp(t2 .deal_date ) - unix_timestamp(t1 .deal_date ) as diff_sec
62+ from tt as t1
63+ inner join tt as t2 on t1 .card_no = t2 .card_no and t1 .px = t2 .px - 1
64+ where t2 .deal_type = ' 地铁出站'
65+ and t1 .deal_type = ' 地铁入站'
66+ and t1 .station <> t2 .station
67+ and substring (t1 .deal_date , 1 , 10 ) = ' 2018-09-01'
68+ and substring (t2 .deal_date , 1 , 10 ) = ' 2018-09-01'
69+ )
70+
71+ select avg (diff_sec)/ 60 from tt2;
72+
73+
74+ -- 地铁主题
75+
76+ -- (基于站点) 进站 top
77+ select station, count (1 ) as cn
78+ from sztcard
79+ where deal_type = ' 地铁入站'
80+ and station > ' '
81+ group by station
82+ order by cn desc
83+ limit 10 ;
84+
85+ -- (基于站点) 出站 top
86+ select station, count (1 ) as cn
87+ from sztcard
88+ where deal_type = ' 地铁出站'
89+ and station > ' '
90+ group by station
91+ order by cn desc
92+ limit 10 ;
93+
94+ -- (基于站点) 进出站 top
95+ select station, count (1 ) as cn
96+ from sztcard
97+ where deal_type in (' 地铁出站' , ' 地铁入站' )
98+ and station > ' '
99+ group by station
100+ order by cn desc
101+ limit 10 ;
102+
103+ -- (基于站点) 站点收入 top
104+ select station, sum (deal_money) / 100 as sm
105+ from sztcard
106+ where deal_type in (' 地铁出站' , ' 地铁入站' )
107+ and station > ' '
108+ group by station
109+ order by sm desc
110+ limit 10 ;
111+
112+ -- (基于线路) 运输贡献度 top
113+ -- 进站算一次,出站并且联程算一次
114+ select company_name, count (1 ) as cn
115+ from sztcard
116+ where company_name rlike ' 地铁'
117+ and (deal_type = ' 地铁出站' and conn_mark = ' 1' or deal_type = ' 地铁入站' )
118+ group by company_name
119+ order by cn desc ;
120+
121+ -- (基于线路) 运输效率 top
122+ -- 每条线路单程直达乘客耗时平均值排行榜
123+ with tt as (
124+ select * , row_number() over( partition by card_no order by deal_date) as px
125+ from sztcard
126+ where deal_type rlike ' 地铁'
127+ ),
128+ tt2 as (
129+ select t1 .card_no ,
130+ t1 .deal_type as in_type, t1 .company_name as in_company, t1 .station as in_station, t1 .deal_date as in_date,
131+ t2 .deal_type as out_type, t2 .company_name as out_company, t2 .station as out_station, t2 .deal_date as out_date,
132+ unix_timestamp(t2 .deal_date ) - unix_timestamp(t1 .deal_date ) as diff_sec
133+ from tt as t1
134+ inner join tt as t2 on t1 .card_no = t2 .card_no and t1 .px = t2 .px - 1
135+ where t2 .deal_type = ' 地铁出站'
136+ and t1 .deal_type = ' 地铁入站'
137+ and t1 .station <> t2 .station
138+ and substring (t1 .deal_date , 1 , 10 ) = ' 2018-09-01'
139+ and substring (t2 .deal_date , 1 , 10 ) = ' 2018-09-01'
140+ )
141+
142+ select in_company, avg (diff_sec) / 60 avg_min
143+ from tt2
144+ where in_company = out_company
145+ group by in_company
146+ order by avg_min;
147+
148+ -- (基于线路) 换乘比例 top
149+ -- 每线路换乘出站乘客百分比排行榜
150+ with tt as (
151+ select * , row_number() over( partition by card_no order by deal_date) as px
152+ from sztcard
153+ where deal_type rlike ' 地铁'
154+ ),
155+ tt2 as (
156+ select t1 .card_no ,
157+ t1 .deal_type as in_type, t1 .company_name as in_company, t1 .station as in_station, t1 .deal_date as in_date,
158+ t2 .deal_type as out_type, t2 .company_name as out_company, t2 .station as out_station, t2 .deal_date as out_date,
159+ t2 .conn_mark ,
160+ unix_timestamp(t2 .deal_date ) - unix_timestamp(t1 .deal_date ) as diff_sec
161+ from tt as t1
162+ inner join tt as t2 on t1 .card_no = t2 .card_no and t1 .px = t2 .px - 1
163+ where t2 .deal_type = ' 地铁出站'
164+ and t1 .deal_type = ' 地铁入站'
165+ and t1 .station <> t2 .station
166+ and substring (t1 .deal_date , 1 , 10 ) = ' 2018-09-01'
167+ and substring (t2 .deal_date , 1 , 10 ) = ' 2018-09-01'
168+ )
169+
170+ select out_company, sum (case when conn_mark = ' 1' then 1 else 0 end) / count (1 ) as per
171+ from tt2
172+ group by out_company
173+ order by per desc ;
174+
175+ -- (基于线路) 线路收入 top
176+ select company_name, sum (deal_money) / 100 as sm
177+ from sztcard
178+ where deal_type rlike ' 地铁'
179+ group by company_name
180+ order by sm desc ;
181+
182+ -- 巴士主题
183+
184+ -- (基于公司) 巴士公司收入 top
185+ select company_name, sum (deal_money) / 100 as sm
186+ from sztcard
187+ where deal_type not rlike ' 地铁'
188+ group by company_name
189+ order by sm desc ;
190+
191+ -- (基于公司) 巴士公司贡献度 top
192+ select company_name, count (1 ) as cn
193+ from sztcard
194+ where deal_type not rlike ' 地铁'
195+ group by company_name
196+ order by cn desc ;
0 commit comments