保单信息.sql 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346
  1. CREATE OR REPLACE PROCEDURE shanglifeecif.init_insurancearrangement_policy_information() -- 创建主存储过程
  2. IS
  3. BEGIN
  4. INSERT INTO shanglifeecif.insurancearrangement(
  5. iaid ,--'保单ID',
  6. policyno ,-- '保险单号 INSURANCEINFO.CONTNO',
  7. pindate ,-- '起保日期 POLICY_INFORMATION.CVALIDATE',
  8. pmdate ,-- '终保日期 POLICY_INFORMATION.ENDDATE',
  9. norenewal ,-- '续保次数 POLICY_INFORMATION.PAYCOUNT',
  10. payment ,-- '缴费方式 POLICY_INFORMATION.PAYINTV',
  11. applicantscustid ,-- '投保人 上游客户号,再找到individualid',
  12. appname ,-- '投保人名称 POLICY_INFORMATION.NAME',
  13. appcertid ,-- '投保人证件号码 POLICY_INFORMATION.IDNO',
  14. insuredscustid ,-- '主被保险人 游客户号',
  15. insname ,-- '主被保险人名称 POLICY_INFORMATION.INSUREDNAME',
  16. inscertid ,-- '主被保险人证件号码 POLICY_INFORMATION.INSUREDIDNO',
  17. productid ,-- '险种代码 POLICY_INFORMATION.RISKCODE',
  18. productname,--险种名称
  19. policybelong ,-- '业绩归属 POLICY_INFORMATION.SALECOM',
  20. payendyear ,-- '缴费年期 POLICY_INFORMATION.PAYENDYEAR',
  21. policystate,--保单状态
  22. prem,--保费
  23. Risk,--保额
  24. NPDate,--下次缴费日期
  25. PADate,--投保日期
  26. pisdate,--签单日期
  27. AgentOrg,--代理机构
  28. schannel,--销售渠道
  29. PWComp,--承保分公司
  30. agrmntage ,--保险期限
  31. created_by ,-- '创建人',
  32. created_time -- '创建时间',
  33. )
  34. SELECT
  35. row_number()over(),
  36. CONTNO,--policyno ,-- '保险单号 INSURANCEINFO.CONTNO',
  37. CVALIDATE,--pindate ,-- '起保日期 POLICY_INFORMATION.CVALIDATE',
  38. ENDDATE,--pmdate ,-- '终保日期 POLICY_INFORMATION.ENDDATE',
  39. PAYCOUNT,--norenewal ,-- '续保次数 POLICY_INFORMATION.PAYCOUNT',
  40. PAYINTV,--payment ,-- '缴费方式 POLICY_INFORMATION.PAYINTV',
  41. CUSTOMERNO,--applicantid ,-- '投保人 根据POLICY_INFORMATION.CUSTOMERNO关联individual上游客户号,再找到individualid',
  42. NAME,--appname ,-- '投保人名称 POLICY_INFORMATION.NAME',
  43. IDNO,--appcertid ,-- '投保人证件号码 POLICY_INFORMATION.IDNO',
  44. insuredno,--insuredid ,-- '主被保险人 insuredno',
  45. INSUREDNAME,--insname ,-- '主被保险人名称 POLICY_INFORMATION.INSUREDNAME',
  46. INSUREDIDNO,--inscertid ,-- '主被保险人证件号码 POLICY_INFORMATION.INSUREDIDNO',
  47. RISKCODE,--productid ,-- '险种代码 POLICY_INFORMATION.RISKCODE',
  48. RISKNAME, --productname 险种名称
  49. SALECOM,--policybelong ,-- '业绩归属 POLICY_INFORMATION.SALECOM',
  50. PAYENDYEAR,--payendyear ,-- '缴费年期 POLICY_INFORMATION.PAYENDYEAR',
  51. APPFLAG, --保单状态
  52. prem,--保费
  53. AMNT,--保额
  54. PAYTODATE,--下次缴费日期
  55. CUSTOMGETPOLDATE,--投保日期
  56. SIGNDATE,--签单日期
  57. AGENTCOM,--代理机构
  58. SALECHNL,--销售渠道
  59. "上海人寿上海分公司",
  60. case
  61. when security ='终身' then 42720
  62. when security = '至100周岁' then 36500
  63. when security = '至80周岁' then 29200
  64. when security = '70年' then 25550
  65. when security = '至70周岁' then 25550
  66. when security = '至65周岁' then 23725
  67. when security = '至60周岁' then 21900
  68. when security = '30年' then 10950
  69. when security = '20年' then 7300
  70. when security = '10年' then 3650
  71. when security = '6年' then 2190
  72. when security = '5年' then 1825
  73. when security = '1年' then 365
  74. when security = '180天' then 180
  75. when security = '6月' then 180
  76. when security = '90天' then 90
  77. when security = '3月' then 90
  78. when security = '1月' then 30
  79. when security = '30天' then 30
  80. when security = '15天' then 15
  81. when security = '7天' then 7
  82. end,
  83. 'admin',
  84. sysdate()
  85. FROM policy_information;
  86. --更新投保人和被保人id 因为 scustid有重复所以需要去下重
  87. UPDATE shanglifeecif.insurancearrangement a SET (
  88. applicantid --'投保人ID',
  89. ) = (
  90. select
  91. c.indid
  92. from (
  93. select
  94. row_number()over(PARTITION BY b.scustid) rn,
  95. b.indid,
  96. b.scustid
  97. from shanglifeecif.individual b
  98. ) c
  99. WHERE c.scustid = a.applicantscustid and c.rn=1
  100. ) WHERE 1=1 ;
  101. UPDATE shanglifeecif.insurancearrangement a SET (
  102. insuredid --'投保人ID',
  103. ) = (
  104. select
  105. c.indid
  106. from (
  107. select
  108. row_number()over(PARTITION BY b.scustid) rn,
  109. b.indid,
  110. b.scustid
  111. from shanglifeecif.individual b
  112. ) c
  113. WHERE c.scustid = a.insuredscustid and c.rn=1
  114. ) WHERE 1=1 ;
  115. --更新INSURANCEINFO 表中的信息
  116. UPDATE shanglifeecif.insurancearrangement a SET (
  117. pano ,-- '投保单号 INSURANCEINFO.PRTNO',
  118. --pisdate ,-- '签单日期 INSURANCEINFO.SIGNDATE',
  119. --padate ,-- '投保日期 INSURANCEINFO.POLAPPLYDATE',
  120. --policystate ,--INSURANCEINFO,appflag
  121. --prem ,-- '总保费 INSURANCEINFO.PREM',
  122. --productname ,-- '险种名称 INSURANCEINFO.RISKNAME'
  123. agentchannel -- '代理渠道 INSURANCEINFO.SELLTYPE',
  124. ) = (
  125. select
  126. PRTNO,--pano ,-- '投保单号 INSURANCEINFO.PRTNO',
  127. --SIGNDATE,--pisdate ,-- '签单日期 INSURANCEINFO.SIGNDATE',
  128. --POLAPPLYDATE,--padate ,-- '投保日期 INSURANCEINFO.POLAPPLYDATE',
  129. --appflag,--policystate ,--INSURANCEINFO,appflag
  130. --PREM,--prem ,-- '总保费 INSURANCEINFO.PREM',
  131. --RISKNAME,--productname ,-- '险种名称 INSURANCEINFO.RISKNAME'
  132. SELLTYPE--agentchannel ,-- '代理渠道 INSURANCEINFO.SELLTYPE',
  133. from INSURANCEINFO b
  134. where b.contno = a.policyno
  135. ) WHERE 1=1 ;
  136. END;
  137. /
  138. CREATE OR REPLACE PROCEDURE shanglifeecif.update_risk_categories() -- 创建主存储过程
  139. IS
  140. BEGIN
  141. --更新险种大类
  142. UPDATE shanglifeecif.insurancearrangement a SET (
  143. risk_categories,
  144. risk_categories_name
  145. ) = (
  146. select
  147. b.kindcode,
  148. (CASE b.kindcode
  149. WHEN 'A' THEN '意外伤害险'
  150. WHEN 'U' THEN '万能保险'
  151. WHEN 'R' THEN '年金保险'
  152. WHEN 'S' THEN '重疾保险'
  153. WHEN 'L' THEN '人寿保险'
  154. WHEN 'H' THEN '健康险'
  155. END) AS kindname
  156. from lmriskapp b WHERE a.productid = b.riskcode
  157. ) WHERE 1=1;
  158. END;
  159. /
  160. /*DROP TABLE IF EXISTS shanglifeecif.insurancearrangement_health_tmp;
  161. CREATE TABLE shanglifeecif.insurancearrangement_health_tmp(
  162. id string,
  163. orderid string DEFAULT NULL COMMENT '用于分组的排序号',
  164. contno string DEFAULT NULL COMMENT '保单号',
  165. AGENTGROUP string DEFAULT NULL COMMENT '承保分公司',--pwcomp ,-- '承保分公司 HEALTH_INSURANCE_LISTING.AGENTGROUPAREA 营业区HEALTH_INSURANCE_LISTING.AGENTGROUP 营业部',
  166. SALECHANNELS string DEFAULT NULL COMMENT '销售渠道',--schannel ,-- '销售渠道 HEALTH_INSURANCE_LISTING.SALECHANNELS 1 2 3 4 5',
  167. AMNT string DEFAULT NULL COMMENT '总保额',--risk ,-- '总保额 HEALTH_INSURANCE_LISTING.AMNT(测试环境中,此表保单数据量较其他表如:POLICY_INFORMATION,INSURANCEINFO 缺少至少一个数据量级)',
  168. AGENTCODE string DEFAULT NULL COMMENT'业务员名称'--spname ,-- '业务员名称 HEALTH_INSURANCE_LISTING.AGENTCODE',
  169. ) COMMENT '保单处理个险承保清单自助分析 数据临时表 '
  170. STORED AS ES
  171. with shard number 10
  172. replication 1;
  173. CREATE OR REPLACE PROCEDURE shanglifeecif.up_insurancearrangement_health_insurance_listing() -- 创建主存储过程
  174. IS
  175. BEGIN
  176. --清空临时表数据
  177. delete from shanglifeecif.insurancearrangement_health_tmp;
  178. --初始化临时表
  179. insert into shanglifeecif.insurancearrangement_health_tmp (
  180. id,
  181. orderid,
  182. contno,
  183. agentgroup,
  184. SALECHANNELS,
  185. AMNT,
  186. AGENTCODE
  187. ) select
  188. row_number()over(),
  189. row_number()over(PARTITION BY contno),
  190. contno,
  191. agentgroup,
  192. SALECHANNELS,
  193. AMNT,
  194. AGENTCODE
  195. from HEALTH_INSURANCE_LISTING
  196. --根据临时表更新insurancearrangement 表
  197. UPDATE shanglifeecif.insurancearrangement a SET (
  198. pwcomp ,-- '承保分公司 HEALTH_INSURANCE_LISTING.AGENTGROUPAREA 营业区HEALTH_INSURANCE_LISTING.AGENTGROUP 营业部',
  199. schannel ,-- '销售渠道 HEALTH_INSURANCE_LISTING.SALECHANNELS 1 2 3 4 5',
  200. risk ,-- '总保额 HEALTH_INSURANCE_LISTING.AMNT(测试环境中,此表保单数据量较其他表如:POLICY_INFORMATION,INSURANCEINFO 缺少至少一个数据量级)',
  201. spname -- '业务员名称 HEALTH_INSURANCE_LISTING.AGENTCODE',
  202. ) = (
  203. select
  204. b.AGENTGROUP,--pwcomp ,-- '承保分公司 HEALTH_INSURANCE_LISTING.AGENTGROUPAREA 营业区HEALTH_INSURANCE_LISTING.AGENTGROUP 营业部',
  205. b.SALECHANNELS,--schannel ,-- '销售渠道 HEALTH_INSURANCE_LISTING.SALECHANNELS 1 2 3 4 5',
  206. b.AMNT,--risk ,-- '总保额 HEALTH_INSURANCE_LISTING.AMNT(测试环境中,此表保单数据量较其他表如:POLICY_INFORMATION,INSURANCEINFO 缺少至少一个数据量级)',
  207. b.AGENTCODE--spname ,-- '业务员名称 HEALTH_INSURANCE_LISTING.AGENTCODE',
  208. from shanglifeecif.insurancearrangement_health_tmp b
  209. where b.contno = a.policyno
  210. and b.orderid = 1
  211. ) WHERE 1=1 ;
  212. END;
  213. */
  214. /
  215. CREATE OR REPLACE PROCEDURE shanglifeecif.up_insurancearrangement_other() -- 创建主存储过程
  216. IS
  217. BEGIN
  218. UPDATE shanglifeecif.insurancearrangement a SET (
  219. policytype -- '保单类型',
  220. ) = (
  221. select
  222. c.CONTTYPE
  223. from (
  224. select
  225. row_number()over(PARTITION BY b.contno) rn,
  226. b.CONTTYPE,
  227. b.contno
  228. from PERSONAL_INSURANCE b
  229. ) c
  230. WHERE c.contno = a.policyno and c.rn=1
  231. ) WHERE 1=1 ;
  232. UPDATE shanglifeecif.insurancearrangement a SET (
  233. poservice -- '是否保全',
  234. ) = (
  235. SELECT
  236. IF(count(b.CONTNO) >0,1,0)
  237. FROM AUDIT_EDORLIST b
  238. where b.contno = a.policyno
  239. ) WHERE 1=1 ;
  240. UPDATE shanglifeecif.insurancearrangement a SET (
  241. soinsured-- '被保人数',
  242. ) = (
  243. SELECT
  244. PEOPLES3
  245. FROM HEALTH_GROUP_LISTING b
  246. where b.contno = a.policyno
  247. ) WHERE 1=1 ;
  248. END;
  249. /
  250. CREATE OR REPLACE PROCEDURE shanglifeecif.init_insurancearrangement() -- 创建主存储过程
  251. IS
  252. BEGIN
  253. --根据policy_information 更新保单表
  254. shanglifeecif.init_insurancearrangement_policy_information();
  255. --根据health_insurance_listing 更新相关字段
  256. shanglifeecif.up_insurancearrangement_health_insurance_listing();
  257. --其他标的字段 更新
  258. shanglifeecif.up_insurancearrangement_other();
  259. END;
  260. /
  261. BEGIN
  262. shanglifeecif.init_insurancearrangement();
  263. end
  264. /*
  265. UPDATE shanglifeecif.insurancearrangement a SET (
  266. pindate ,-- '起保日期 POLICY_INFORMATION.CVALIDATE',
  267. pmdate ,-- '终保日期 POLICY_INFORMATION.ENDDATE',
  268. norenewal ,-- '续保次数 POLICY_INFORMATION.PAYCOUNT',
  269. payment ,-- '缴费方式 POLICY_INFORMATION.PAYINTV',
  270. applicantscustid ,-- '投保人 上游客户号,再找到individualid',
  271. appname ,-- '投保人名称 POLICY_INFORMATION.NAME',
  272. appcertid ,-- '投保人证件号码 POLICY_INFORMATION.IDNO',
  273. insuredscustid ,-- '主被保险人 游客户号',
  274. insname ,-- '主被保险人名称 POLICY_INFORMATION.INSUREDNAME',
  275. inscertid ,-- '主被保险人证件号码 POLICY_INFORMATION.INSUREDIDNO',
  276. productid ,-- '险种代码 POLICY_INFORMATION.RISKCODE',
  277. productname,--险种名称
  278. policybelong ,-- '业绩归属 POLICY_INFORMATION.SALECOM',
  279. payendyear ,-- '缴费年期 POLICY_INFORMATION.PAYENDYEAR',
  280. policystate,--保单状态
  281. prem,--保费
  282. Risk,--保额
  283. NPDate,--下次缴费日期
  284. PADate,--投保日期
  285. AgentOrg,--代理机构
  286. schannel,--销售渠道
  287. PWComp--承保分公司
  288. ) = (
  289. select
  290. CVALIDATE,--pindate ,-- '起保日期 POLICY_INFORMATION.CVALIDATE',
  291. ENDDATE,--pmdate ,-- '终保日期 POLICY_INFORMATION.ENDDATE',
  292. PAYCOUNT,--norenewal ,-- '续保次数 POLICY_INFORMATION.PAYCOUNT',
  293. PAYINTV,--payment ,-- '缴费方式 POLICY_INFORMATION.PAYINTV',
  294. CUSTOMERNO,--applicantid ,-- '投保人 根据POLICY_INFORMATION.CUSTOMERNO关联individual上游客户号,再找到individualid',
  295. NAME,--appname ,-- '投保人名称 POLICY_INFORMATION.NAME',
  296. IDNO,--appcertid ,-- '投保人证件号码 POLICY_INFORMATION.IDNO',
  297. insuredno,--insuredid ,-- '主被保险人 insuredno',
  298. INSUREDNAME,--insname ,-- '主被保险人名称 POLICY_INFORMATION.INSUREDNAME',
  299. INSUREDIDNO,--inscertid ,-- '主被保险人证件号码 POLICY_INFORMATION.INSUREDIDNO',
  300. RISKCODE,--productid ,-- '险种代码 POLICY_INFORMATION.RISKCODE',
  301. RISKNAME, --productname 险种名称
  302. SALECOM,--policybelong ,-- '业绩归属 POLICY_INFORMATION.SALECOM',
  303. PAYENDYEAR,--payendyear ,-- '缴费年期 POLICY_INFORMATION.PAYENDYEAR',
  304. APPFLAG, --保单状态
  305. prem,--保费
  306. AMNT,--保额
  307. PAYTODATE,--下次缴费日期
  308. CUSTOMGETPOLDATE,--投保日期
  309. AGENTCOM,--代理机构
  310. SALECHNL,--销售渠道
  311. "上海人寿上海分公司"
  312. from shanghailifeecif.policy_information b
  313. where b.contno = a.policyno
  314. ) WHERE 1=1 ;
  315. */