123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506 |
- CREATE OR REPLACE PROCEDURE shanglifeecif.init_individual_main()
- IS
- DECLARE
- individual_count int
- strsql string
- BEGIN
- shanglifeecif.customertotaltemp();
- DELETE FROM shanglifeecif.individual;
-
- shanglifeecif.init_all_individual();
-
- shanglifeecif.up_t_customers_class_1();
-
- shanglifeecif.up_other_customerinfo()
- END;
- /
- CREATE OR REPLACE PROCEDURE shanglifeecif.customertotaltemp() IS
- DECLARE
- BEGIN
- DELETE FROM shanglifeecif.customertotaltemp;
- insert into shanglifeecif.customertotaltemp(
- scustid,
- name,
- gender,
- birthday,
- idcard,
- idtype
- )
- SELECT
- scustid ,
- max(name) as name,
- max(gender) as gender ,
- to_char(max(birthday),"yyyy-MM-dd") birthday,
- max(idcard) as idcard,
- max(idtype) AS idtype
- FROM (
- SELECT
- trim(customerno) AS scustid,
- trim(name) AS name,
- trim(sex) AS gender,
- trim(birthday) AS birthday,
- trim(idtype) AS idtype ,
- trim(idno) AS idcard
- FROM
- policy_information
- WHERE customerno IS NOT NULL
- UNION
- SELECT
- trim(insuredno) AS scustid,
- trim(insuredname) AS name,
- trim(insuredsex) AS gender,
- trim(insuredbirthday) AS birthday,
- trim(insuredidtype) AS idtype ,
- trim(insuredidno) AS idcard
- FROM
- policy_information
- WHERE insuredno IS NOT NULL
- ) tmpTable GROUP BY scustid;
-
- UPDATE shanglifeecif.customertotaltemp sct SET sct.mobile = (SELECT trim(t.MOBILE) FROM t_customer_class t WHERE sct.scustid=t.customer_id);
- EXCEPTION
- WHEN HIVE_EXCEPTION THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- WHEN Others THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- END ;
- /
- CREATE OR REPLACE PROCEDURE shanglifeecif.init_all_individual()
- IS
- BEGIN
-
-
- insert into shanglifeecif.individual (
- indid,
- custid,
- scustid,
- name,
- gender,
- birthday,
- idcard,
- Passport,
- Dlicense,
- OtherIdNumber,
- created_time,
- created_by
- ) SELECT
- row_number()OVER(ORDER BY sc.scustid),
- 'CP'||lpad(row_number()over(ORDER BY sc.scustid),10,'0'),
- sc.scustid,
- sc.name,
- sc.gender,
- sc.birthday,
- CASE sc.idtype WHEN '0' THEN sc.idcard END AS idcard,
- CASE sc.idtype WHEN '1' THEN sc.idcard END AS passport,
- CASE sc.idtype WHEN '3' THEN sc.idcard END AS dlicense,
- CASE WHEN sc.idtype <> '0' AND sc.idtype <> '1' AND sc.idtype <> '3' THEN sc.idcard END AS otherIdnumber,
- sysdate,
- 'admin'
-
- FROM shanglifeecif.customertotaltemp sc ORDER BY sc.scustid;
-
-
- EXCEPTION
- WHEN HIVE_EXCEPTION THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- WHEN Others THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- END;
- CREATE OR REPLACE PROCEDURE shanglifeecif.up_t_customers_class_1()
- IS
- BEGIN
- UPDATE shanglifeecif.individual a SET (
- CustClass ,
- ConValue ,
- Awarded3 ,
- Awarded2 ,
- Awarded1 ,
- SOValue ,
- EndDate,
- Height,
- Weight,
- BMI,
- PIncome,
- FIncome,
- IncomeSource,
- SIStatus,
-
- Nation,
- MaritalStat,
- Employer,
- Education,
- Dday,
- regtype,
- ZIPCODE,
- HPhone,
- PMPhone,
- email,
- RAL,
- sobirth
- ) = (
- select
- b.CLASS_VALUE,
- b.CONTRIBUTION_VALUE,
- b.AWARDED3,
- b.AWARDED2,
- b.AWARDED1,
- b.TOTAL_VALUE,
- trim(b.END_DATE) as END_DATE,
- b.STATURE,
- b.AVOIRDUPOIS,
- b.BMI,
- b.YEARINCOME,
- b.FAMILYYEARSALARY,
- trim(b.INCOMESOURCE) as INCOMESOURCE,
- trim(b.SOCIALINSUFLAG) as SOCIALINSUFLAG,
-
- trim(b.NATIVEPLACE) as NATIVEPLACE,
- trim(b.MARRIAGE) as MARRIAGE,
- trim(b.GRPNAME) as GRPNAME,
- trim(b.DEGREE) as DEGREE,
- trim(b.DEATHDATE) as DEATHDATE,
- trim(b.DENTYPE) as DENTYPE,
- trim(b.ZIPCODE) as ZIPCODE,
- trim(b.PHONE) as PHONE,
- trim(b.MOBILE) as MOBILE,
- trim(b.EMAIL) as EMAIL,
- regexp_replace(trim(b.POSTALADDRESS),'[0-9]','*') as POSTALADDRESS,
- regexp_extract(b.POSTALADDRESS,'(.*?)省|(.*?)市',0)
- from t_customer_class b
- where b.CUSTOMER_ID = a.scustid
- ) WHERE 1=1 ;
- EXCEPTION
- WHEN HIVE_EXCEPTION THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- WHEN Others THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- END;
- /
- CREATE OR REPLACE PROCEDURE shanglifeecif.up_other_customerinfo()
- IS
- BEGIN
-
-
- UPDATE shanglifeecif.individual i SET i.custtype = '投保人' WHERE
- i.scustid IN (SELECT p.customerno FROM policy_information p);
-
- UPDATE shanglifeecif.individual i SET i.custtype = '被保人' WHERE
- i.scustid IN (SELECT pi.insuredno FROM policy_information pi);
-
- UPDATE shanglifeecif.individual i SET i.custtype = '投保人、被保人' WHERE
- i.scustid IN (SELECT p.customerno FROM policy_information p)
- AND i.scustid IN (SELECT pi.insuredno FROM policy_information pi);
-
-
- UPDATE shanglifeecif.Individual si1 SET si1.policybelong = (
- SELECT trim(t.SALECOM) FROM (
- SELECT row_number()OVER(PARTITION BY p.customerno ORDER BY p.polapplydate asc) rd,p.customerno,p.SALECOM FROM policy_information p
- ) t WHERE t.rd = 1 AND si1.scustid = t.customerno
- );
-
- UPDATE shanglifeecif.Individual si1 SET si1.policybelong = (
- SELECT trim(t.SALECOM) FROM (
- SELECT row_number()OVER(PARTITION BY p.insuredno ORDER BY p.polapplydate asc) rd,p.insuredno,p.SALECOM FROM policy_information p
- ) t WHERE t.rd = 1 AND si1.scustid = t.insuredno
- );
-
-
- UPDATE shanglifeecif.Individual si1 SET (si1.Occupation,si1.Ethnic) = (
- SELECT trim(t.occupationname),trim(t.NATIONALITYNAME) FROM (
- SELECT row_number()OVER(PARTITION BY p.customerno ORDER BY p.polapplydate desc) rd,p.customerno,p.occupationname,p.NATIONALITYNAME FROM policy_information p
- ) t WHERE t.rd = 1 AND si1.scustid = t.customerno
- );
-
-
- UPDATE shanglifeecif.individual si SET si.officialCalculus = (
- SELECT temp.available_points FROM (SELECT t.available_points,t.certificate_no,row_number()OVER(PARTITION BY t.certificate_no ORDER BY t.gmt_created DESC) rd FROM t_account t) temp WHERE temp.rd = 1 AND temp.certificate_no = si.idcard
- );
-
- EXCEPTION
- WHEN HIVE_EXCEPTION THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- WHEN Others THEN
- INSERT INTO shanglifeecif.exception_log(log_code,log_msg,log_time) VALUES (sqlcode(),sqlerrm(),sysdate());
- END;
- /
- BEGIN
- shanglifeecif.init_individual_main();
- end ;
|