-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathTPCDI_Loader.py
1644 lines (1559 loc) · 72.4 KB
/
TPCDI_Loader.py
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
import os
import glob
import xmltodict
import oracledb
import pickle
from utils import char_insert
class TPCDI_Loader():
BASE_SQL_CMD = ""
def __init__(self, sf, config, batch_number, drop_sql, create_sql, load_path, overwrite=False):
"""
Initialize staging database.
Attributes:
sf (str): Scale factor to be used in benchmark.
db_name (str): Name of database schema to which the data will be loaded.
config (config list): Config object retrieved from calling ConfigParser().read().
batch_number (int): Batch number that going to be processed
drop_sql (str): Path to the sql file for dropping all the tables
create_sql (str): Path to the sql file for creating all the tables
load_path (str): Path to the directory load, where all sql files are located
"""
self.sf = sf
self.batch_number = batch_number
self.batch_dir = "../staging/"+self.sf+"/Batch"+str(self.batch_number)+"/"
self.load_path = load_path
self.oracle_user = config['ORACLESQL_SERVER']['oracle_user']
self.oracle_pwd = config['ORACLESQL_SERVER']['oracle_pwd']
self.oracle_host = config['ORACLESQL_SERVER']['oracle_host']
self.oracle_db = config['ORACLESQL_SERVER']['oracle_db']
# Construct base oraclesql command (set host, port, and user)
TPCDI_Loader.BASE_SQL_CMD = 'sqlplus %s/%s@%s/%s' % (
self.oracle_user, self.oracle_pwd, self.oracle_host, self.oracle_db)
TPCDI_Loader.BASE_SQLLDR_CMD = 'sqlldr userid=%s/%s@%s/%s' % (
self.oracle_user, self.oracle_pwd, self.oracle_host, self.oracle_db
)
# Drop database if it is exists and overwrite param is set to True
if overwrite:
# dropping the tables
cmd = TPCDI_Loader.BASE_SQL_CMD+' @%s' % (drop_sql)
os.system(cmd)
# Create the tables
cmd = TPCDI_Loader.BASE_SQL_CMD+' @%s' % (create_sql)
os.system(cmd)
def load_current_batch_date(self):
print("Loading batch date...")
with open(self.batch_dir+"BatchDate.txt", "r") as batch_date_file:
cmd = TPCDI_Loader.BASE_SQL_CMD+' @%s' % (self.load_path+'/BatchDate.sql')
cmd += ' %s %s' % (self.batch_number,batch_date_file.read().strip())
os.system(cmd)
print("Done.")
def load_dim_date(self):
"""
Create DimDate table in the staging database and then load rows in Date.txt into it.
"""
print("Loading dim date...")
# Create query to load text data into dimDate table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/DimDate.ctl', self.batch_dir + 'Date.txt')
os.system(cmd)
print("Done.")
def load_dim_time(self):
"""
Create DimTime table in the staging database and then load rows in Time.txt into it.
"""
print("Loading dim time...")
# Create query to load text data into dimTime table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/DimTime.ctl', self.batch_dir + 'Time.txt')
os.system(cmd)
print("Done.")
def load_industry(self):
"""
Create Industry table in the staging database and then load rows in Industry.txt into it.
"""
print("Loading industry...")
# Create query to load text data into industry table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/Industry.ctl', self.batch_dir + 'Industry.txt')
os.system(cmd)
print("Done.")
def load_status_type(self):
"""
Create StatusType table in the staging database and then load rows in StatusType.txt into it.
"""
print("Loading status type...")
# Create query to load text data into statusType table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/StatusType.ctl', self.batch_dir + 'StatusType.txt')
os.system(cmd)
print("Done.")
def load_tax_rate(self):
"""
Create TaxRate table in the staging database and then load rows in TaxRate.txt into it.
"""
print("Loading tax rate...")
# Create query to load text data into taxRate table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/TaxRate.ctl', self.batch_dir + 'TaxRate.txt')
os.system(cmd)
print("Done.")
def load_trade_type(self):
"""
Create TradeType table in the staging database and then load rows in TradeType.txt into it.
"""
print("Loading trade type...")
# Create query to load text data into tradeType table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/TradeType.ctl', self.batch_dir + 'TradeType.txt')
os.system(cmd)
print("Done.")
def load_staging_customer_account(self):
print("Loading staging customer and account...")
customer_inserts = []
account_inserts = []
max_packet = 150
with open(self.batch_dir + '/CustomerMgmt.xml') as fd:
doc = xmltodict.parse(fd.read())
actions = doc['TPCDI:Actions']['TPCDI:Action']
for action in actions:
action_type = action['@ActionType']
# Customer fields
try:
c_id = action['Customer']['@C_ID']
except:
c_id = None
try:
c_tax_id = action['Customer']['@C_TAX_ID']
except:
c_tax_id = None
try:
c_l_name = action['Customer']['Name']['C_L_NAME']
except:
c_l_name = None
try:
c_f_name = action['Customer']['Name']['C_F_NAME']
except:
c_f_name = None
try:
c_m_name = action['Customer']['Name']['C_M_NAME']
except:
c_m_name = None
try:
c_tier = action['Customer']['@C_TIER']
if c_tier == '':
c_tier = 0
except:
c_tier = 0
try:
c_dob = action['Customer']['@C_DOB']
except:
c_dob = None
try:
c_prim_email = action['Customer']['ContactInfo']['C_PRIM_EMAIL']
except:
c_prim_email = None
try:
c_alt_email = action['Customer']['ContactInfo']['C_ALT_EMAIL']
except:
c_alt_email = None
try:
c_gndr = action['Customer']['@C_GNDR'].upper()
except:
c_gndr = 'U'
if c_gndr != 'M' and c_gndr != 'F':
c_gndr = 'U'
try:
c_adline1 = action['Customer']['Address']['C_ADLINE1']
except:
c_adline1 = None
try:
c_adline2 = action['Customer']['Address']['C_ADLINE2']
except:
c_adline2 = None
try:
c_zipcode = action['Customer']['Address']['C_ZIPCODE']
except:
c_zipcode = None
try:
c_city = action['Customer']['Address']['C_CITY']
except:
c_city = None
try:
c_state_prov = action['Customer']['Address']['C_STATE_PROV']
except:
c_state_prov = None
try:
c_ctry = action['Customer']['Address']['C_CTRY']
except:
c_ctry = None
c_status = 'ACTIVE'
phones = []
try:
phones.append(action['Customer']['ContactInfo']['C_PHONE_1'])
except:
phones.append(None)
try:
phones.append(action['Customer']['ContactInfo']['C_PHONE_2'])
except:
phones.append(None)
try:
phones.append(action['Customer']['ContactInfo']['C_PHONE_3'])
except:
phones.append(None)
phone_numbers = []
for phone in phones:
try:
c_ctry_code = phone['C_CTRY_CODE']
except:
c_ctry_code = None
try:
c_area_code = phone['C_AREA_CODE']
except:
c_area_code = None
try:
c_local = phone['C_LOCAL']
except:
c_local = None
phone_number = None
if c_ctry_code is not None and c_area_code is not None and c_local is not None:
phone_number = '+' + c_ctry_code + '(' + c_area_code + ')' + c_local
elif c_ctry_code is None and c_area_code is not None and c_local is not None:
phone_number = '(' + c_area_code + ')' + c_local
elif c_ctry_code is None and c_area_code is None and c_local is not None:
phone_number = c_local
if phone_number is not None and phone['C_EXT'] is not None:
phone_number = phone_number + phone['C_EXT']
phone_numbers.append(phone_number)
try:
c_nat_tx_id = action['Customer']['TaxInfo']['C_NAT_TX_ID']
except:
c_nat_tx_id = None
try:
c_lcl_tx_id = action['Customer']['TaxInfo']['C_LCL_TX_ID']
except:
c_lcl_tx_id = None
try:
action_ts_date = action['@ActionTS'][0:10]
except:
action_ts_date = None
if c_id is not None:
insert_customer = f"""
INSERT INTO S_Customer (ActionType, CustomerID, TaxID, Status, LastName, FirstName, MiddleInitial, Gender, Tier, DOB, AddressLine1, AddressLine2, PostalCode,
City, StateProv, Country, Phone1, Phone2, Phone3, Email1, Email2, NationalTaxRateDesc, NationalTaxRate, LocalTaxRateDesc, LocalTaxRate, EffectiveDate, EndDate, BatchId)
VALUES ('{char_insert(action_type)}', {c_id}, '{char_insert(c_tax_id)}', '{char_insert(c_status)}', '{char_insert(c_l_name)}', '{char_insert(c_f_name)}', '{char_insert(c_m_name)}',
'{char_insert(c_gndr)}', {c_tier}, TO_DATE('{char_insert(c_dob)}', 'yyyy-mm-dd'), '{char_insert(c_adline1)}', '{char_insert(c_adline2)}', '{char_insert(c_zipcode)}',
'{char_insert(c_city)}', '{char_insert(c_state_prov)}', '{char_insert(c_ctry)}', '{char_insert(phone_numbers[0])}', '{char_insert(phone_numbers[1])}',
'{char_insert(phone_numbers[2])}', '{char_insert(c_prim_email)}', '{char_insert(c_alt_email)}',
(SELECT TX_NAME FROM TaxRate WHERE TX_ID = '{char_insert(c_nat_tx_id)}'), (SELECT TX_RATE FROM TaxRate WHERE TX_ID = '{char_insert(c_nat_tx_id)}'),
(SELECT TX_NAME FROM TaxRate WHERE TX_ID = '{char_insert(c_lcl_tx_id)}'), (SELECT TX_RATE FROM TaxRate WHERE TX_ID = '{char_insert(c_lcl_tx_id)}'),
TO_DATE('{char_insert(action_ts_date)}', 'yyyy-mm-dd'), TO_DATE('9999-12-31', 'yyyy-mm-dd'), {self.batch_number})
"""
customer_inserts.append(insert_customer)
# Account fields
try:
a_id = action['Customer']['Account']['@CA_ID']
except:
a_id = None
try:
a_Desc = action['Customer']['Account']['CA_NAME']
except:
a_Desc = None
try:
a_taxStatus = action['Customer']['Account']['@CA_TAX_ST']
except:
a_taxStatus = None
try:
a_brokerID = action['Customer']['Account']['CA_B_ID']
except:
a_brokerID = None
# action_type we have it already
try:
action_ts_date = action['@ActionTS'][0:10]
except:
action_ts_date = None
if a_id is not None:
insert_account = f"""
INSERT INTO S_Account (ActionType, AccountID, Status, BrokerID, CustomerID, AccountDesc, TaxStatus, EffectiveDate, EndDate, BatchId)
VALUES ('{char_insert(action_type)}', {a_id}, 'Active', '{char_insert(a_brokerID)}', '{char_insert(c_id)}', '{char_insert(a_Desc)}', '{char_insert(a_taxStatus)}',
TO_DATE('{char_insert(action_ts_date)}', 'yyyy-mm-dd'), TO_DATE('9999-12-31', 'yyyy-mm-dd'), {self.batch_number})
"""
account_inserts.append(insert_account)
if len(customer_inserts) + len(account_inserts) >= max_packet:
# Create query to load text data into tradeType table
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
for ins in customer_inserts:
cursor.execute(ins)
connection.commit()
customer_inserts = []
for ins in account_inserts:
cursor.execute(ins)
connection.commit()
account_inserts = []
print('Done.')
def load_new_customer(self):
"""
Load NEW customers into DimCustomer table
"""
print('Loading new customers into DimCustomer table...')
# First, we insert all NEW customers into the DimCustomer table
load_query = """
INSERT INTO DimCustomer(CustomerID, TaxID, Status, LastName, FirstName, MiddleInitial, Gender, Tier, DOB, AddressLine1, AddressLine2, PostalCode,
City, StateProv, Country, Phone1, Phone2, Phone3, Email1, Email2, NationalTaxRateDesc, NationalTaxRate, LocalTaxRateDesc, LocalTaxRate, EffectiveDate,
EndDate, BatchId, AgencyID, CreditRating, NetWorth, MarketingNameplate, IsCurrent)
WITH Copied AS (
SELECT C.CustomerID, C.TaxID, C.Status, C.LastName, C.FirstName, C.MiddleInitial, C.Gender, C.Tier, C.DOB, C.AddressLine1, C.AddressLine2, C.PostalCode,
C.City, C.StateProv, C.Country, C.Phone1, C.Phone2, C.Phone3, C.Email1, C.Email2, C.NationalTaxRateDesc, C.NationalTaxRate, C.LocalTaxRateDesc, C.LocalTaxRate, C.EffectiveDate,
C.EndDate, C.BatchId, P.AgencyID, P.CreditRating, P.NetWorth, P.MarketingNameplate
FROM Prospect P, S_Customer C
WHERE C.ActionType = 'NEW' AND
P.FirstName = C.FirstName AND
UPPER(P.LastName) = UPPER(C.LastName) AND
TRIM(UPPER(P.AddressLine1)) = TRIM(UPPER(C.AddressLine1)) AND
TRIM(UPPER(P.AddressLine2)) = TRIM(UPPER(C.AddressLine2)) AND
TRIM(UPPER(P.PostalCode)) = TRIM(UPPER(C.PostalCode)) AND
NOT EXISTS (SELECT *
FROM S_Customer C1
WHERE C.CustomerID = C1.CustomerID AND
(C1.ActionType = 'UPDCUST' OR C1.ActionType = 'INACT') AND
C1.EffectiveDate > C.EffectiveDate
)
)
SELECT C.CustomerID, C.TaxID, C.Status, C.LastName, C.FirstName, C.MiddleInitial, C.Gender, C.Tier, C.DOB, C.AddressLine1, C.AddressLine2, C.PostalCode,
C.City, C.StateProv, C.Country, C.Phone1, C.Phone2, C.Phone3, C.Email1, C.Email2, C.NationalTaxRateDesc, C.NationalTaxRate, C.LocalTaxRateDesc, C.LocalTaxRate, C.EffectiveDate,
C.EndDate, C.BatchId, CP.AgencyID, CP.CreditRating, CP.NetWorth, CP.MarketingNameplate, 'true'
FROM S_Customer C LEFT OUTER JOIN Copied CP ON (C.CustomerID = CP.CustomerID)
WHERE C.ActionType = 'NEW'
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(load_query)
connection.commit()
print('Done.')
def load_new_account(self):
"""
Load NEW accounts in S_Account into DimAccount table in the target database.
"""
print('Loading new accounts...')
# First, we insert all NEW rows from S_Account into DimAccount
load_query = """
INSERT INTO DimAccount (AccountID, SK_BrokerID, SK_CustomerID, Status, AccountDesc, TaxStatus, IsCurrent, BatchID, EffectiveDate, EndDate)
WITH Copied AS (
SELECT A.AccountID, B.SK_BrokerID, C.SK_CustomerID, A.Status, A.AccountDesc, A.TaxStatus, A.BatchID, A.EffectiveDate, A.EndDate
FROM S_Account A
JOIN DimBroker B ON A.BrokerID = B.BrokerID
JOIN DimCustomer C ON A.CustomerID = C.CustomerID
WHERE A.ActionType IN ('NEW', 'ADDACCT') AND
NOT EXISTS (
SELECT * FROM S_Account A1
WHERE A.AccountID = A1.AccountID AND
(A1.ActionType = 'UPDACC' OR A1.ActionType = 'INACT') AND
A1.EffectiveDate > A.EffectiveDate
)
)
SELECT A.AccountID, CP.SK_BrokerID, CP.SK_CustomerID, A.Status, A.AccountDesc, A.TaxStatus, 'true', A.BatchID, A.EffectiveDate, A.EndDate
FROM S_Account A
LEFT OUTER JOIN Copied CP ON (A.AccountID = CP.AccountID)
WHERE A.ActionType IN ('NEW', 'ADDACCT')
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(load_query)
connection.commit()
print('Done.')
def create_trigger_UPD_customer_account(self):
"""
Create a trigger that will update the DimAccount table when a customer is updated.
"""
print('Creating trigger UPD_CUSTOMER_ACCOUNT...')
create_trigger_query = """
CREATE OR REPLACE TRIGGER UPD_CUSTOMER_ACCOUNT
AFTER UPDATE OF SK_CustomerID ON DimAccount
FOR EACH ROW
BEGIN
UPDATE DimAccount
SET SK_CustomerID = :new.SK_CustomerID
WHERE AccountID = :old.AccountID;
END;
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(create_trigger_query)
connection.commit()
print('Done.')
def load_update_customer(self):
# Now we update all fields in the DimCustomer table with the latest values from S_Customer
print('Updating DimCustomer table...')
base_update_query = """
UPDATE DimCustomer C
SET %s = (
SELECT MAX(%s)
FROM S_Customer C1
WHERE C1.CustomerID = C.CustomerID AND
C1.%s IS NOT NULL AND
C1.ActionType = 'UPDCUST' AND
NOT EXISTS (
SELECT * FROM S_Customer C2
WHERE C2.CustomerID = C1.CustomerID
AND C2.ActionType = 'UPDCUST' AND C2.EffectiveDate > C1.EffectiveDate)
)
WHERE EXISTS (
SELECT * FROM S_Customer C1
WHERE C1.CustomerID = C.CustomerID AND
C1.%s IS NOT NULL AND
C1.ActionType = 'UPDCUST' AND
NOT EXISTS (
SELECT * FROM S_Customer C2
WHERE C2.CustomerID = C1.CustomerID AND
C2.ActionType = 'UPDCUST' AND C2.EffectiveDate > C1.EffectiveDate)
)
"""
update_query_status = base_update_query % ('C.Status', 'C1.Status', 'Status', 'Status')
update_query_last_name = base_update_query % ('C.LastName', 'C1.LastName', 'LastName', 'LastName')
update_query_first_name = base_update_query % ('C.FirstName', 'C1.FirstName', 'FirstName', 'FirstName')
update_query_middle_initial = base_update_query % ('C.MiddleInitial', 'C1.MiddleInitial', 'MiddleInitial', 'MiddleInitial')
update_query_gender = base_update_query % ('C.Gender', 'C1.Gender', 'Gender', 'Gender')
update_query_tier = base_update_query % ('C.Tier', 'C1.Tier', 'Tier', 'Tier')
update_query_dob = base_update_query % ('C.DOB', 'C1.DOB', 'DOB', 'DOB')
update_query_address_line1 = base_update_query % ('C.AddressLine1', 'C1.AddressLine1', 'AddressLine1', 'AddressLine1')
update_query_address_line2 = base_update_query % ('C.AddressLine2', 'C1.AddressLine2', 'AddressLine2', 'AddressLine2')
update_query_postal_code = base_update_query % ('C.PostalCode', 'C1.PostalCode', 'PostalCode', 'PostalCode')
update_query_city = base_update_query % ('C.City', 'C1.City', 'City', 'City')
update_query_state_prov = base_update_query % ('C.StateProv', 'C1.StateProv', 'StateProv', 'StateProv')
update_query_country = base_update_query % ('C.Country', 'C1.Country', 'Country', 'Country')
update_query_phone1 = base_update_query % ('C.Phone1', 'C1.Phone1', 'Phone1', 'Phone1')
update_query_phone2 = base_update_query % ('C.Phone2', 'C1.Phone2', 'Phone2', 'Phone2')
update_query_phone3 = base_update_query % ('C.Phone3', 'C1.Phone3', 'Phone3', 'Phone3')
update_query_email1 = base_update_query % ('C.Email1', 'C1.Email1', 'Email1', 'Email1')
update_query_email2 = base_update_query % ('C.Email2', 'C1.Email2', 'Email2', 'Email2')
update_query_national_tax_rate_desc = base_update_query % ('C.NationalTaxRateDesc', 'C1.NationalTaxRateDesc', 'NationalTaxRateDesc', 'NationalTaxRateDesc')
update_query_national_tax_rate = base_update_query % ('C.NationalTaxRate', 'C1.NationalTaxRate', 'NationalTaxRate', 'NationalTaxRate')
update_query_local_tax_rate_desc = base_update_query % ('C.LocalTaxRateDesc', 'C1.LocalTaxRateDesc', 'LocalTaxRateDesc', 'LocalTaxRateDesc')
update_query_local_tax_rate = base_update_query % ('C.LocalTaxRate', 'C1.LocalTaxRate', 'LocalTaxRate', 'LocalTaxRate')
# To finalize the update, we need to update the values from Prospect
base_update_prospect_query = """
UPDATE DimCustomer C
SET C.AgencyID = (
SELECT MAX(CP.AgencyID)
FROM (SELECT P.AgencyID
FROM Prospect P
WHERE P.FirstName = C.FirstName AND
UPPER(P.LastName) = UPPER(C.LastName) AND
TRIM(UPPER(P.AddressLine1)) = TRIM(UPPER(C.AddressLine1)) AND
TRIM(UPPER(P.AddressLine2)) = TRIM(UPPER(C.AddressLine2)) AND
TRIM(UPPER(P.PostalCode)) = TRIM(UPPER(C.PostalCode))
) CP),
C.CreditRating = (
SELECT MAX(CP.CreditRating)
FROM (SELECT P.CreditRating
FROM Prospect P
WHERE P.FirstName = C.FirstName AND
UPPER(P.LastName) = UPPER(C.LastName) AND
TRIM(UPPER(P.AddressLine1)) = TRIM(UPPER(C.AddressLine1)) AND
TRIM(UPPER(P.AddressLine2)) = TRIM(UPPER(C.AddressLine2)) AND
TRIM(UPPER(P.PostalCode)) = TRIM(UPPER(C.PostalCode))
) CP),
C.NetWorth = (
SELECT MAX(CP.NetWorth)
FROM (SELECT P.NetWorth
FROM Prospect P
WHERE P.FirstName = C.FirstName AND
UPPER(P.LastName) = UPPER(C.LastName) AND
TRIM(UPPER(P.AddressLine1)) = TRIM(UPPER(C.AddressLine1)) AND
TRIM(UPPER(P.AddressLine2)) = TRIM(UPPER(C.AddressLine2)) AND
TRIM(UPPER(P.PostalCode)) = TRIM(UPPER(C.PostalCode))
) CP),
C.MarketingNameplate = (
SELECT MAX(CP.MarketingNameplate)
FROM (SELECT P.MarketingNameplate
FROM Prospect P
WHERE P.FirstName = C.FirstName AND
UPPER(P.LastName) = UPPER(C.LastName) AND
TRIM(UPPER(P.AddressLine1)) = TRIM(UPPER(C.AddressLine1)) AND
TRIM(UPPER(P.AddressLine2)) = TRIM(UPPER(C.AddressLine2)) AND
TRIM(UPPER(P.PostalCode)) = TRIM(UPPER(C.PostalCode))
) CP)
WHERE EXISTS (
SELECT * FROM S_Customer C1
WHERE C1.CustomerID = C.CustomerID AND
C1.ActionType = 'UPDCUST' AND
NOT EXISTS (
SELECT * FROM S_Customer C2
WHERE C2.CustomerID = C1.CustomerID AND
C2.ActionType = 'UPDCUST' AND C2.EffectiveDate > C1.EffectiveDate)
)
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
print('...')
cursor.execute(update_query_status)
cursor.execute(update_query_last_name)
cursor.execute(update_query_first_name)
print('...')
cursor.execute(update_query_middle_initial)
cursor.execute(update_query_gender)
cursor.execute(update_query_tier)
print('...')
cursor.execute(update_query_dob)
cursor.execute(update_query_address_line1)
cursor.execute(update_query_address_line2)
print('...')
cursor.execute(update_query_postal_code)
cursor.execute(update_query_city)
cursor.execute(update_query_state_prov)
print('...')
cursor.execute(update_query_country)
cursor.execute(update_query_phone1)
cursor.execute(update_query_phone2)
print('...')
cursor.execute(update_query_phone3)
cursor.execute(update_query_email1)
cursor.execute(update_query_email2)
print('...')
cursor.execute(update_query_national_tax_rate_desc)
cursor.execute(update_query_national_tax_rate)
cursor.execute(update_query_local_tax_rate_desc)
cursor.execute(update_query_local_tax_rate)
print('...')
cursor.execute(base_update_prospect_query)
connection.commit()
print('Done.')
def load_update_account(self):
# Now we update the DimAccount table
print('Updating accounts...')
base_update_query = """
UPDATE DimAccount A
SET A.%s = (
SELECT MAX(A1.%s)
FROM S_Account A1
WHERE A1.AccountID = A.AccountID AND
A1.%s IS NOT NULL AND
A1.ActionType = 'UPDACCT' AND
NOT EXISTS (
SELECT * FROM S_Account A2
WHERE A2.AccountID = A1.AccountID AND
A2.ActionType = 'UPDACCT' AND A2.EffectiveDate > A1.EffectiveDate)
)
WHERE EXISTS (
SELECT * FROM S_Account A1
WHERE A1.AccountID = A.AccountID AND
A1.%s IS NOT NULL AND
A1.ActionType = 'UPDACCT' AND
NOT EXISTS (
SELECT * FROM S_Account A2
WHERE A2.AccountID = A1.AccountID AND
A2.ActionType = 'UPDACCT' AND A2.EffectiveDate > A1.EffectiveDate)
)
"""
update_query_status = base_update_query % ('Status', 'Status', 'Status', 'Status')
update_query_account_desc = base_update_query % ('AccountDesc', 'AccountDesc', 'AccountDesc', 'AccountDesc')
update_query_account_taxstatus = base_update_query % ('TaxStatus', 'TaxStatus', 'TaxStatus', 'TaxStatus')
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(update_query_status)
cursor.execute(update_query_account_desc)
cursor.execute(update_query_account_taxstatus)
connection.commit()
print('Done.')
def load_close_account(self):
# Now, we update the Status field for all rows in the DimAccount table
# for which there is a row in S_Account with an ActionType of 'CLOSEACCT'
print('Closing accounts...')
update_query_status = """
UPDATE DimAccount A
SET A.Status = 'Inactive'
WHERE EXISTS (
SELECT * FROM S_Account A1
WHERE A1.AccountID = A.AccountID AND
A1.ActionType = 'CLOSEACCT' AND
NOT EXISTS (
SELECT * FROM S_Account A2
WHERE A2.AccountID = A1.AccountID AND
A2.ActionType = 'UPDACCT' AND A2.EffectiveDate > A1.EffectiveDate)
)
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(update_query_status)
connection.commit()
print('Done.')
def load_inact_customer(self):
# Finally, we update the EndDate field and the isCurrent field for all rows in the DimCustomer table
# for which there is a row in S_Customer with an ActionType of 'INACT'
print('Updating inactive customers...')
update_query_end_date = """
UPDATE DimCustomer C
SET C.EndDate = (
SELECT MAX(C1.EffectiveDate)
FROM S_Customer C1
WHERE C1.CustomerID = C.CustomerID AND
C1.ActionType = 'INACT' AND
NOT EXISTS (
SELECT * FROM S_Customer C2
WHERE C2.CustomerID = C1.CustomerID AND
C2.ActionType = 'INACT' AND C2.EffectiveDate > C1.EffectiveDate)
),
C.isCurrent = 'false'
WHERE EXISTS (
SELECT * FROM S_Customer C1
WHERE C1.CustomerID = C.CustomerID AND
C1.ActionType = 'INACT' AND
NOT EXISTS (
SELECT * FROM S_Customer C2
WHERE C2.CustomerID = C1.CustomerID AND
C2.ActionType = 'INACT' AND C2.EffectiveDate > C1.EffectiveDate)
)
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(update_query_end_date)
connection.commit()
print('Done.')
print('Adding invalid Customer records to DImessages...')
query = """INSERT INTO DImessages
(MessageDateAndTime, BatchID, MessageSource, MessageText, MessageType, MessageData)
SELECT CURRENT_TIMESTAMP, C.BatchID, 'DimCustomer', 'Invalid customer tier', 'Alert', 'C_ID = ' || C.CustomerID || ', C_TIER = ' || C.Tier
FROM DimCustomer C
WHERE C.Tier not in (1, 2, 3)"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(query)
connection.commit()
query = "select BatchDate, BatchDate-NUMTOYMINTERVAL(100, 'year') from BatchDate where BatchNumber = 1"
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(query)
for i in cursor:
b_date, b_date_100 = i
break
b_date_100 = b_date_100.strftime('%Y-%m-%d')
b_date = b_date.strftime('%Y-%m-%d')
query = """insert into DImessages (MessageDateAndTime, BatchID, MessageSource, MessageText, MessageType, MessageData)
SELECT CURRENT_TIMESTAMP, C.BatchID, 'DimCustomer', 'DOB is out of range', 'Alert', 'C_ID = ' || C.CustomerID || ', C_DOB = ' || C.DOB
FROM DimCustomer C
where ( (TO_DATE(\'%s\', 'yyyy-mm-dd') > DOB) or (DOB > (TO_DATE(\'%s\', 'yyyy-mm-dd'))) )"""%(b_date_100, b_date)
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(query)
connection.commit()
print("Done.")
def load_inact_account(self):
# Finally, we update the EndDate field, the Status and the isCurrent field for all rows in the DimAccount table
# for which there is a row in S_Account with an ActionType of 'INACT'
print('Updating inactive accounts...')
update_query_end_date = """
UPDATE DimAccount A
SET A.EndDate = (
SELECT MAX(A1.EffectiveDate)
FROM S_Account A1
WHERE A1.AccountID = A.AccountID AND
A1.ActionType = 'INACT' AND
NOT EXISTS (
SELECT * FROM S_Account A2
WHERE A2.AccountID = A1.AccountID AND
A2.ActionType = 'INACT' AND A2.EffectiveDate > A1.EffectiveDate)
),
A.Status = 'Inactive',
A.isCurrent = 'false'
WHERE EXISTS (
SELECT * FROM S_Account A1
WHERE A1.AccountID = A.AccountID AND
A1.ActionType = 'INACT' AND
NOT EXISTS (
SELECT * FROM S_Account A2
WHERE A2.AccountID = A1.AccountID AND
A2.ActionType = 'INACT' AND A2.EffectiveDate > A1.EffectiveDate)
)
"""
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(update_query_end_date)
connection.commit()
print('Done.')
def update_prospect(self):
upd_query = """
UPDATE Prospect P
SET P.IsCustomer = 'true'
WHERE EXISTS (
SELECT *
FROM DimCustomer C
WHERE UPPER(P.LastName) = UPPER(C.LastName) AND
TRIM(UPPER(P.AddressLine1)) = TRIM(UPPER(C.AddressLine1)) AND
TRIM(UPPER(P.AddressLine2)) = TRIM(UPPER(C.AddressLine2)) AND
TRIM(UPPER(P.PostalCode)) = TRIM(UPPER(C.PostalCode))
)
"""
print('Updating prospect customer info...')
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(upd_query)
connection.commit()
print('Done.')
print('Filling DImessages for Prospect')
query = """INSERT INTO DImessages
(MessageDateAndTime, BatchID, MessageSource, MessageText, MessageType, MessageData)
SELECT CURRENT_TIMESTAMP,%s,'Prospect', 'Inserted rows', 'Status', COUNT(*) FROM Prospect
"""%(str(self.batch_number))
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(query)
connection.commit()
print('Done.')
def load_staging_broker(self):
"""
Load rows in HR.csv into S_Broker table in staging database.
"""
print('Loading staging broker...')
# Create query to load txt data into S_Watches table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/Broker.ctl', self.batch_dir + 'HR.csv')
os.system(cmd)
print('Done.')
def load_broker(self):
"""
Create DimBroker table in the target database and then load rows in HR.csv into it.
"""
print('Loading broker...')
load_dim_broker_query = """
INSERT INTO DimBroker (BrokerID,ManagerID,FirstName,LastName,MiddleInitial,Branch,Office,Phone,IsCurrent,BatchID,EffectiveDate,EndDate)
SELECT SB.EmployeeID, SB.ManagerID, SB.EmployeeFirstName, SB.EmployeeLastName, SB.EmployeeMI, SB.EmployeeBranch, SB.EmployeeOffice, SB.EmployeePhone, 'true', %d, (SELECT MIN(DateValue) FROM DimDate), TO_DATE('9999/12/31', 'yyyy/mm/dd')
FROM S_Broker SB
WHERE SB.EmployeeJobCode = 314
""" % (self.batch_number)
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(load_dim_broker_query)
connection.commit()
print('Done.')
def load_staging_cash_balances(self):
"""
Load rows in CashTransaction.txt into S_Cash_Balances table in staging database.
"""
print('Loading staging cash balances...')
# Create query to load txt data into S_Watches table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/CashBalances.ctl', self.batch_dir + 'CashTransaction.txt')
os.system(cmd)
print('Done.')
def load_cash_balances(self):
print('Loading FactCashBalances...')
insert_query = """
INSERT INTO FactCashBalances (SK_CustomerID, SK_AccountID, SK_DateID, Cash, BatchID)
SELECT SK_CustomerID, SK_AccountID, SK_DateID, SUM(CT_AMT) OVER (PARTITION BY SK_AccountID ORDER BY DateValue) Cash, {0} BatchID
FROM S_Cash_Balances CB INNER JOIN DimAccount DA ON (CB.CT_CA_ID = DA.AccountID)
INNER JOIN DimDate DD ON (TO_CHAR(CB.CT_DTS, 'YYYY-MM-DD') = TO_CHAR(DateValue, 'YYYY-MM-DD'))
WHERE DA.EffectiveDate <= CB.CT_DTS AND CB.CT_DTS <= DA.EndDate
""".format(self.batch_number)
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host + '/' + self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(insert_query)
connection.commit()
print('Done.')
def load_staging_watches(self):
"""
Load rows in WatchHistory.txt into S_Watches table in staging database.
"""
print('Loading staging watches...')
# Create query to load txt data into S_Watches table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/Watches.ctl', self.batch_dir + 'WatchHistory.txt')
os.system(cmd)
print('Done.')
def load_watches(self):
print('Loading FactWatches...')
insert_watches_query = """
INSERT INTO FactWatches (SK_CustomerID, SK_SecurityID, SK_DateID_DatePlaced, SK_DateID_DateRemoved, BatchID)
WITH Active AS (
SELECT W_C_ID, W_S_SYMB, DC.SK_CustomerID, DS.SK_SecurityID, DD.SK_DateID
FROM S_Watches W
INNER JOIN DimCustomer DC ON (W.W_C_ID = DC.CUSTOMERID)
INNER JOIN DimSecurity DS ON (W.W_S_SYMB = DS.Symbol)
INNER JOIN DimDate DD ON (TO_CHAR(W.W_DTS, 'YYYY-MM-DD') = TO_CHAR(DD.DateValue, 'YYYY-MM-DD'))
WHERE W.W_ACTION = 'ACTV'
),
Cancelled AS (
SELECT W_C_ID, W_S_SYMB, DD.SK_DateID
FROM S_Watches W
INNER JOIN DimDate DD ON (TO_CHAR(W.W_DTS, 'YYYY-MM-DD') = TO_CHAR(DD.DateValue, 'YYYY-MM-DD'))
WHERE W.W_ACTION = 'CNCL'
)
SELECT A.SK_CustomerID, A.SK_SecurityID, A.SK_DateID, C.SK_DateID, {0} BatchID
FROM Active A LEFT OUTER JOIN Cancelled C ON (A.W_C_ID = C.W_C_ID AND A.W_S_SYMB = C.W_S_SYMB)
""".format(self.batch_number)
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host + '/' + self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(insert_watches_query)
connection.commit()
print('Done.')
def load_staging_holdings(self):
"""
Load rows in HoldingHistory.txt into S_Holdings table in staging database.
"""
print('Loading staging holdings...')
# Create query to load txt data into S_Holdings table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD + ' control=%s data=%s' % (
self.load_path + '/Holdings.ctl', self.batch_dir + 'HoldingHistory.txt')
os.system(cmd)
print('Done.')
def load_fact_holdings(self):
print('Loading FactHoldings...')
insert_holdings_query = """
INSERT INTO FactHoldings(TradeId, CurrentTradeID, SK_CustomerID, SK_AccountID, SK_SecurityID, SK_CompanyID, SK_DateID, SK_TimeID, CurrentPrice, CurrentHolding, BatchID)
SELECT HH_H_T_ID AS TradeId, HH_T_ID AS CurrentTradeID, DT.SK_CustomerID, DT.SK_AccountID, DT.SK_SecurityID, DT.SK_CompanyID, DT.SK_CloseDateID AS SK_DateID, DT.SK_CloseTimeID AS SK_TimeID, DT.TradePrice AS CurrentPrice, HH_AFTER_QTY AS CurrentHolding, 1 AS BatchID
FROM S_Holdings H
INNER JOIN DimTrade DT ON (H.HH_T_ID = DT.TradeID)
WHERE DT.SK_CloseDateID IS NOT NULL AND DT.SK_CloseTimeID IS NOT NULL
""".format(self.batch_number)
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host + '/' + self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(insert_holdings_query)
connection.commit()
print('Done.')
def load_staging_prospect(self):
"""
Load rows in Prospect.csv into S_Prospect table in staging database.
"""
print('Loading staging prospect...')
# Create query to load csv data into S_Prospect table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/Prospect.ctl', self.batch_dir + 'Prospect.csv')
os.system(cmd)
print('Done.')
rowcount = 0
for _ in open(self.batch_dir + 'Prospect.csv'):
rowcount+= 1
print(rowcount)
query = """INSERT INTO DImessages
(MessageDateAndTime, BatchID, MessageSource, MessageText, MessageType, MessageData)
VALUES (CURRENT_TIMESTAMP,%s,'Prospect', 'Source rows', 'Status',\'%s\')
"""%(str(self.batch_number), str(rowcount))
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(query)
connection.commit()
def load_prospect(self):
print('Loading prospect...')
marketing_nameplate_func = """
CREATE OR REPLACE FUNCTION get_marketing_template(net_worth NUMBER, income NUMBER,
number_credit_cards NUMBER, number_children NUMBER, age NUMBER,
credit_rating NUMBER, number_cars NUMBER)
RETURN VARCHAR AS
marketing_template VARCHAR(100);
BEGIN
IF (net_worth>1000000 OR income>200000) THEN
marketing_template := CONCAT(marketing_template, 'HighValue+');
END IF;
IF (number_credit_cards>5 OR number_children>3) THEN
marketing_template := CONCAT(marketing_template, 'Expenses+');
END IF;
IF (age>45) THEN
marketing_template := CONCAT(marketing_template, 'Boomer+');
END IF;
IF (credit_rating<600 or income <5000 or net_worth < 100000) THEN
marketing_template := CONCAT(marketing_template, 'MoneyAlert+');
END IF;
IF (number_cars>3 or number_credit_cards>7) THEN
marketing_template := CONCAT(marketing_template, 'Spender+');
END IF;
IF (age>25 or net_worth>1000000) THEN
marketing_template := CONCAT(marketing_template, 'Inherited+');
END IF;
RETURN SUBSTR(marketing_template, 1, LENGTH(marketing_template) - 1);
END;
"""
load_prospect_query = """
INSERT INTO Prospect
SELECT SP.AGENCY_ID, (SELECT SK_DateID FROM DimDate WHERE DateValue IN (SELECT BatchDate FROM BatchDate WHERE BatchNumber = {0})) SK_RecordDateID,
(SELECT SK_DateID FROM DimDate WHERE DateValue IN (SELECT BatchDate FROM BatchDate WHERE BatchNumber = {0})) SK_UpdateDateID, {0} BatchID,
'false' IsCustomer, SP.LAST_NAME, SP.FIRST_NAME, SP.MIDDLE_INITIAL, SP.GENDER, SP.ADDRESS_LINE_1, SP.ADDRESS_LINE_2, SP.POSTAL_CODE, SP.CITY,
SP.STATE, SP.COUNTRY, SP.PHONE, SP.INCOME, SP.NUMBER_CARS,SP.NUMBER_CHILDREM, SP.MARITAL_STATUS, SP.AGE,
SP.CREDIT_RATING, SP.OWN_OR_RENT_FLAG, SP.EMPLOYER,SP.NUMBER_CREDIT_CARDS, SP.NET_WORTH,
get_marketing_template(SP.NET_WORTH, SP.INCOME, SP.NUMBER_CREDIT_CARDS, SP.NUMBER_CHILDREM, SP.AGE, SP.CREDIT_RATING, SP.NUMBER_CARS) MarketingNameplate
FROM S_Prospect SP
""".format(self.batch_number)
with oracledb.connect(
user=self.oracle_user, password=self.oracle_pwd,
dsn=self.oracle_host+'/'+self.oracle_db) as connection:
with connection.cursor() as cursor:
cursor.execute(marketing_nameplate_func)
cursor.execute(load_prospect_query)
connection.commit()
print('Done.')
def load_audit(self):
"""
Create Audit table in the staging database and then load rows in files with "_audit.csv" ending into it.
"""
print('Loading staging audit...')
for filepath in glob.iglob(self.batch_dir+"*_audit.csv"):# Create query to load text data into tradeType table
cmd = TPCDI_Loader.BASE_SQLLDR_CMD+' control=%s data=%s' % (self.load_path+'/Audit.ctl', filepath)
os.system(cmd)
print('Done.')
def load_staging_finwire(self):
"""
Create S_Company and S_Security table in the staging database and then load rows in FINWIRE files with the type of CMP
"""
print('Loading staging company, security and financial...')
base_path = "../staging/"+self.sf+"/Batch1/"
s_company_base_query = "INSERT INTO S_Company"
s_security_base_query = "INSERT INTO S_Security"
s_financial_base_query = "INSERT INTO S_Financial"
s_company_values = []
s_security_values = []
s_financial_values = []
max_packet = 150
for fname in os.listdir(base_path):
if("FINWIRE" in fname and "audit" not in fname):
with open(base_path+fname, 'r') as finwire_file:
for line in finwire_file:
pts = line[:15] #0
rec_type=line[15:18] #1
if rec_type=="CMP":
company_name = line[18:78] #2
# check if company name is made of blanks
if company_name.strip() == "":
company_name = "NULL"
cik = line[78:88] #3
status = line[88:92] #4
industry_id = line[92:94] #5
sp_rating = line[94:98] # 6
# check if sp rating is made of blanks
if sp_rating.strip() == "":
sp_rating = "NULL"