-
Notifications
You must be signed in to change notification settings - Fork 4
/
Copy pathImport_X12_999.sql
117 lines (97 loc) · 3.88 KB
/
Import_X12_999.sql
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
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER OFF
GO
Create procedure [dbo].[Import_X12_999] @path As varChar(128), @filename As varChar(64), @emailRecipient As varChar(128)
As
Begin
Truncate Table tbl_X12_999_Import
Declare @BulkCmd As nvarChar(4000)
Set @BulkCmd = "BULK INSERT tbl_X12_999_Import FROM '"+@path+@filename+"' WITH (ROWTERMINATOR='\n')"
Exec (@BulkCmd)
Declare @query As varchar(max), @body As varChar(max), @kount As int
Set @kount = (Select count(*) From tbl_X12_999_Import)
if @kount > 0
Begin
If OBJECT_ID('tempdb..##TEMP_X12_999_1') Is Not Null
Drop Table ##TEMP_X12_999_1
If OBJECT_ID('tempdb..##TEMP_X12_999_2') Is Not Null
Drop Table ##TEMP_X12_999_2
If OBJECT_ID('tempdb..##TEMP_X12_999_3') Is Not Null
Drop Table ##TEMP_X12_999_3
If OBJECT_ID('tempdb..##TEMP_X12_999_4') Is Not Null
Drop Table ##TEMP_X12_999_4
If OBJECT_ID('tempdb..##TEMP_X12_999_5') Is Not Null
Drop Table ##TEMP_X12_999_5
-- Parse the tbl_X12_999_Import table into separate fields
Select X.col001 As WholeRecord
, SUBSTRING(X.col001,1,CHARINDEX('*',X.col001)-1) As Segment
, SUBSTRING(X.col001,CHARINDEX('*',X.col001)+1,LEN(X.col001)-CHARINDEX('*',X.col001)) As col001
Into ##TEMP_X12_999_1
From tbl_X12_999_Import As X
Select WholeRecord
, X.Segment
, Case When CHARINDEX('*',X.col001)=0 Then X.col001
Else SUBSTRING(X.col001,1,CHARINDEX('*',X.col001)-1) End As F1
, Case When CHARINDEX('*',X.col001)=0 Then ''
Else SUBSTRING(X.col001,CHARINDEX('*',X.col001)+1,LEN(X.col001)-CHARINDEX('*',X.col001)) End As col001
Into ##TEMP_X12_999_2
From ##TEMP_X12_999_1 As X
Select WholeRecord
, X.Segment
, X.F1
, Case When CHARINDEX('*',X.col001)=0 Then X.col001
Else SUBSTRING(X.col001,1,CHARINDEX('*',X.col001)-1) End As F2
, Case When CHARINDEX('*',X.col001)=0 Then ''
Else SUBSTRING(X.col001,CHARINDEX('*',X.col001)+1,LEN(X.col001)) End As col001
Into ##TEMP_X12_999_3
From ##TEMP_X12_999_2 As X
Select WholeRecord
, X.Segment
, X.F1
, X.F2
, Case When CHARINDEX('*',X.col001)=0 Then X.col001
Else SUBSTRING(X.col001,1,CHARINDEX('*',X.col001)-1) End As F3
, Case When CHARINDEX('*',X.col001)=0 Then ''
Else SUBSTRING(X.col001,CHARINDEX('*',X.col001)+1,LEN(X.col001)) End As col001
Into ##TEMP_X12_999_4
From ##TEMP_X12_999_3 As X
Select WholeRecord
, X.Segment
, X.F1
, X.F2
, X.F3
, Case When CHARINDEX('*',X.col001)=0 Then X.col001
Else SUBSTRING(X.col001,1,CHARINDEX('*',X.col001)-1) End As F4
, Case When CHARINDEX('*',X.col001)=0 Then ''
Else SUBSTRING(X.col001,CHARINDEX('*',X.col001)+1,LEN(X.col001)) End As col001
Into ##TEMP_X12_999_5
From ##TEMP_X12_999_4 As X
Set @query="Set NOCOUNT On; Select Top 100 WholeRecord+Case When E1.Error_Msg Is Null Then '<br />' Else ' <== <b><i>'+E1.Error_Msg+'</i></b><br />' End
From ##TEMP_X12_999_5 As X
Left Outer Join X12_999_ErrorMessage As E1 On E1.Error_ID=X.Segment And (E1.Error_Seq='' Or E1.Error_Seq=X.F1)"
Set @body='<font face="Consolas,Monaco,Lucida Console,Liberation Mono,DejaVu Sans Mono,Bitstream Vera Sans Mono,Courier New, monospace">'
Set @body=@body+@path+@filename+'<br /><br />'
Declare @subject As char(128)
Set @subject='[Important]: '+@filename+' X12 834 file validation'
-- Email the first 100 lines of the file
EXEC msdb..sp_send_dbmail
@profile_name='YourMailProfile',
@recipients=@emailRecipient,
@subject=@subject,
@body=@body,
@body_format='HTML',
@query=@query,
@query_result_header=0
If OBJECT_ID('tempdb..##TEMP_X12_999_1') Is Not Null
Drop Table ##TEMP_X12_999_1
If OBJECT_ID('tempdb..##TEMP_X12_999_2') Is Not Null
Drop Table ##TEMP_X12_999_2
If OBJECT_ID('tempdb..##TEMP_X12_999_3') Is Not Null
Drop Table ##TEMP_X12_999_3
If OBJECT_ID('tempdb..##TEMP_X12_999_4') Is Not Null
Drop Table ##TEMP_X12_999_4
If OBJECT_ID('tempdb..##TEMP_X12_999_5') Is Not Null
Drop Table ##TEMP_X12_999_5
End
End