Commit 0dc20455 authored by 赵建伟's avatar 赵建伟

Merge branch 'wangyan' into 'master'

Wangyan

See merge request !17
parents 7f844cc0 384e3c97
.idea/dataSources/
lib/java/bi-report-service/.idea/workspace.xml
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
search_related=转诊基础明细数据表
zhuanzhen_base_data=转诊基础明细数据表
\ No newline at end of file
#step1_1.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online tl_hdfs_api_bdtransfer_view
\ No newline at end of file
#step1_2.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online tl_hdfs_api_bdtransfer_singlerecord_view
\ No newline at end of file
#step1_3.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online ml_meigou_order_detail
\ No newline at end of file
#step1_4.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online tl_hdfs_budan_view
\ No newline at end of file
#step1_6.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online tl_hdfs_api_bdtransfer_singlerecord_project_view
\ No newline at end of file
#step1_7.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online tl_hdfs_api_tag_view
\ No newline at end of file
#step1_8.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive tl tl_zx_api_bdtransfer_willing_project
\ No newline at end of file
#step1_9.job
type=command
command=sh /home/bi/bi-report/lib/shell/waitsuccess.sh hive online bl_city_updates
\ No newline at end of file
#step2.job
type=command
dependencies=step1_1,step1_2,step1_3,step1_4,step1_6,step1_7,step1_8,step1_9
command=curl -X GET http://localhost:8553/api/report/email/zhuanzhen_base_data/zhouming@igengmei.com,jianzirui@igengmei.com/wangyan@igengmei.com,zhaofei@igengmei.com
\ No newline at end of file
----转诊基础明细数据(从当月1号累计)
SELECT
coalesce(t1.pooled_date,0) as `入池时间`
,t1.id as `转诊线索ID`
,coalesce(t1.people_city_name,'未填写') as `用户所在的城市`
,coalesce(t1.age,'未填写') as `用户年龄`
,coalesce(t1.gender,0) as `用户性别`
,collect_set(t1.willing_tag_name) as `意向项目`
,coalesce(t1.paidan_city,'无') as `派单城市`
,coalesce(t1.hospital_name,'无') as `机构名称`
,coalesce(t1.single_id,0) as `派单ID`
,coalesce(t1.paidan_tag_name,'无') as `派单项目`
,collect_set(t2.name) as `成单项目`
,coalesce(t1.source,0) as `渠道`
,coalesce(user.name,'无') as `跟进顾问`
,coalesce(t1.status_t,0) as `对象状态`
,coalesce(t1.status_s,'无') as `订单状态`
,coalesce(t2.extra_consume,0) as `成单金额`
,coalesce(t2.payment,0) as `佣金金额`
,coalesce(t1.budan_id,0) as `补单ID`
from
(--线索,pooled_time字段20200326仓库更新加入
SELECT
transfer.current_follow_up_consultant_id as follow_user_id--跟进顾问
,transfer.id as id ---转诊线索ID
,city.city_name as people_city_name---城市名称
,transfer.age as age ---年龄
,transfer.gender as gender --性别
,c.willing_tag_name as willing_tag_name ---意向项目
,singlerecord.budan_id as budan_id---补单ID
,singlerecord.id as single_id ---派单ID
,case when transfer.source=0 then '其他'
when transfer.source=6 then '更美后台'
when transfer.source=40 then '内投-PC首页'
when transfer.source=41 then '内投-M站首页'
when transfer.source=42 then '内投-APP首页(更美咨询)'
when transfer.source=43 then '内投-APP首页(老客)'
when transfer.source=44 then '内投-APP首页(新人)'
when transfer.source=45 then '内投-APP美购页'
when transfer.source=46 then '内投-APP客服中心'
when transfer.source=47 then '内投-APP豆腐块'
when transfer.source=48 then '内投-公众号'
when transfer.source=49 then '内投-微博'
when transfer.source=50 then '内投-医生待咨询'
when transfer.source=51 then '内投-知乎'
when transfer.source=52 then '内投-小红书'
when transfer.source=53 then '外投-市场提供数据'
when transfer.source=54 then '其他-客户转介绍'
when transfer.source=55 then '其他-沉睡客户激活'
when transfer.source=10 then '陌陌秒杀'
when transfer.source=11 then '百度品专'
when transfer.source=12 then '百度搜索'
when transfer.source=13 then '今日头条'
when transfer.source=14 then '陌陌IOS'
when transfer.source=15 then '百度原生'
when transfer.source=16 then '爱奇艺信息流'
when transfer.source=17 then '陌陌微信号'
when transfer.source=39 then '旧版更美APP(7740版本以前)'
when transfer.source=56 then '朋友推荐'
when transfer.source=57 then '内部员工'
when transfer.source=58 then '老带新'
when transfer.source=59 then '公众号客服消息'
when transfer.source=60 then '公众号文章评论'
when transfer.source=61 then '电话名单顾客'
else '' end as source---来源
,transfer.pooled_date as pooled_date--入池时间
,case when transfer.object_state=1 then '未通过消息'
when transfer.object_state=2 then '已通过消息'
when transfer.object_state=3 then '已派单'
when transfer.object_state=4 then '已预约'
when transfer.object_state=5 then '已面诊'
when transfer.object_state=6 then '已成单'
when transfer.object_state=7 then '已终止'
end as status_t--对象状态
,case when singlerecord.status=0 then '已派单'
when singlerecord.status=1 then '已成单'
when singlerecord.status=2 then '已撤销'
when singlerecord.status=3 then '已预约'
when singlerecord.status=4 then '已面诊'
when singlerecord.status=5 then '已终止'
when singlerecord.status=6 then '已接单'
when singlerecord.status=7 then '已重单'
end as status_s---派单状态
,meigou.service_city_name as paidan_city---城市
,meigou.hospital_name as hospital_name
,bd.paidan_tag_name as paidan_tag_name---派单项目名称
--- ,COUNT(DISTINCT t1.id) as clue_num
FROM
(
SELECT
a.id as id
,a.pooled_date as pooled_date
,a.source as source
,a.current_follow_up_consultant_id as current_follow_up_consultant_id
,a.object_state as object_state
,a.user_city as user_city
,a.age as age
,case when a.gender in ('2') then '女'
when a.gender in ('1') then '男'
else '未填写' end as gender
----,d.name as tag_name ---意向项目
FROM
(
SELECT id,substr(pooled_time,0,10) as pooled_date,current_follow_up_consultant_id
,source,object_state,user_city,age,gender
FROM online.tl_hdfs_api_bdtransfer_view
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
AND SUBSTR(pooled_time,0,10) >= trunc(date_sub(current_date(),1),'MM')
AND SUBSTR(pooled_time,0,10) < current_date()
AND current_follow_up_consultant_id is not null
)a
)transfer
LEFT JOIN
(
SELECT dbtransfer_id,id,user_id,single_time,doctor_id,status,budan_id
FROM online.tl_hdfs_api_bdtransfer_singlerecord_view --存在同一个线索多次派单情况
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
--状态 1-已成单
)singlerecord
ON transfer.id=singlerecord.dbtransfer_id
LEFT JOIN
(----派单城市
SELECT doctor_id,service_city_name,hospital_name
FROM online.ml_meigou_order_detail
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)meigou
on meigou.doctor_id=singlerecord.doctor_id
LEFT JOIN
(----派单项目
SELECT
a.bdtransfersinglerecord_id as bdtransfersinglerecord_id
,tag.name as paidan_tag_name
FROM
(
SELECT bdtransfersinglerecord_id,tag_id
from online.tl_hdfs_api_bdtransfer_singlerecord_project_view
WHERE partition_date =REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)a
JOIN
(
SELECT id,name
FROM online.tl_hdfs_api_tag_view
WHERE partition_date =REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)tag
on tag.id=a.tag_id
)bd
on bd.bdtransfersinglerecord_id=singlerecord.id
left JOIN
(----意向项目名称
SELECT
a.bdtransfer_id as bdtransfer_id
,tag.name as willing_tag_name
FROM
(
select tag_id ,bdtransfer_id
from tl.tl_zx_api_bdtransfer_willing_project
where partition_day=REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)a
JOIN
(
select id,name
from online.tl_hdfs_api_tag_view
where partition_date=REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)tag
on a.tag_id=tag.id
)c
on c.bdtransfer_id=transfer.id
left JOIN
(----用户所在城市
SELECT city_id,city_name
FROM online.bl_city_updates
WHERE partition_date=REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)city
on transfer.user_city=city.city_id
)t1
LEFT JOIN
(---成单金额和佣金金额
SELECT
singlerecord.budan_id as budan_id
,dev.name as name
,coalesce(budan.extra_consume,0)-coalesce(revocation.extra_consume,0) as extra_consume--成单金额
,coalesce(budan.payment,0)-coalesce(revocation.payment,0) as payment--成单金额
FROM
(
SELECT id,substr(pooled_time,0,10) as pooled_date,current_follow_up_consultant_id,source
FROM online.tl_hdfs_api_bdtransfer_view
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
AND SUBSTR(pooled_time,0,10) >= trunc(date_sub(current_date(),1),'MM')
AND SUBSTR(pooled_time,0,10)< current_date()
)transfer
JOIN
(
SELECT dbtransfer_id,id,user_id,single_time,doctor_id,status,budan_id
FROM online.tl_hdfs_api_bdtransfer_singlerecord_view --存在同一个线索多次派单情况
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)singlerecord
ON transfer.id=singlerecord.dbtransfer_id
JOIN
(
SELECT id,extra_consume,payment,create_time,budan_type
FROM online.tl_hdfs_budan_view -- 补单表
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
AND status in ('0','6')
AND budan_type = '1'
)budan
ON singlerecord.budan_id=budan.id
join
(
select id,dev_project.money as money,dev_project.rate as rate
,dev_project.name as name
FROM
(
SELECT id,json_split(t.dev_projects) dev_projects
from online.tl_hdfs_budan_view t
WHERE partition_date = REGEXP_REPLACE(date_sub(current_date(),1),'-','')
)t1
lateral view explode(t1.dev_projects) t2 as dev_project
lateral view json_tuple(dev_project,'money','rate','name') dev_project as money,rate,name
---group by id,dev_project.money,dev_project.rate
)dev
on dev.id=budan.id
FULL JOIN
(----跨月撤销的情况(需要剔除)
SELECT id,user_phone,doctor_id,extra_consume,payment,budan_type
FROM online.tl_hdfs_budan_view -- 补单表
WHERE partition_date =REGEXP_REPLACE(date_sub(current_date(),1),'-','')
AND status ='2'
AND budan_type = '1'
AND is_monthly_revocation = 'true'
)revocation
ON singlerecord.budan_id=revocation.id
group by singlerecord.budan_id, dev.name ,coalesce(budan.extra_consume,0)-coalesce(revocation.extra_consume,0),coalesce(budan.payment,0)-coalesce(revocation.payment,0)
)t2
on t1.budan_id=t2.budan_id
LEFT JOIN
(
SELECT name,user_id,joined_date
FROM tl.tl_pm_consultation_counsellor
GROUP BY name,user_id,joined_date
)user
ON user.user_id = t1.follow_user_id
GROUP by
coalesce(t1.pooled_date,0)
,t1.id
,coalesce(t1.people_city_name,'未填写')
,coalesce(t1.age,'未填写')
,coalesce(t1.gender,0)
,coalesce(t1.paidan_city,'无')
,coalesce(t1.hospital_name,'无')
,coalesce(t1.single_id,0)
,coalesce(t1.paidan_tag_name,'无')
,coalesce(t1.source,0)
,coalesce(user.name,'无')
,coalesce(t1.status_t,0)
,coalesce(t1.status_s,'无')
,coalesce(t2.extra_consume,0)
,coalesce(t2.payment,0)
,coalesce(t1.budan_id,0)
ORDER BY `入池时间`
\ No newline at end of file
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
File mode changed from 100755 to 100644
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment