-
Notifications
You must be signed in to change notification settings - Fork 1
/
Sequel.p
366 lines (256 loc) · 10.7 KB
/
Sequel.p
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
&SCOPED-DEFINE Sequel PRESENT
{Sequel.i}
{constants.i}
/* Define how to connect to SQL server */
&SCOPED-DEFINE sqlserver 192.168.1.240
&SCOPED-DEFINE sqluser username
&SCOPED-DEFINE sqlpass passw0rd
/* Set these to the SQL database name of your live and test environments */
&SCOPED-DEFINE sqlLiveDB live
&SCOPED-DEFINE sqlTestDB test
&SCOPED-DEFINE batchcount 100
/*******************************************************************************
SQL SERVER CONNECTIONS
*******************************************************************************/
CREATE "ADODB.Connection":U SequelCon.
CREATE "ADODB.Command":U SequelCmd.
CREATE "ADODB.RecordSet":U SequelRes.
PROCEDURE ConnectLive:
SequelCon:OPEN("Driver=~{SQL Server};Server={&sqlserver};Database={&sqlLiveDB};UID={&sqluser};PWD={&sqlpass}":U, , , 0).
END PROCEDURE.
PROCEDURE ConnectTest:
SequelCon:OPEN("Driver=~{SQL Server};Server={&sqlserver};Database={&sqlTestDB};UID={&sqluser};PWD={&sqlpass}":U, , , 0).
END PROCEDURE.
PROCEDURE CloseConnect:
SequelCon:CLOSE NO-ERROR.
END PROCEDURE.
/*******************************************************************************
LOGGING
*******************************************************************************/
DEF STREAM oLog.
PROCEDURE openStream:
OUTPUT STREAM oLog TO VALUE("c:\temp\sequel_log.txt":U) APPEND.
END PROCEDURE.
PROCEDURE closeStream:
OUTPUT STREAM oLog CLOSE.
END PROCEDURE.
PROCEDURE writeStream:
DEF INPUT PARAMETER s AS CHAR NO-UNDO.
PUT STREAM oLog UNFORMATTED s SKIP.
END PROCEDURE.
PROCEDURE LogEntry:
DEF INPUT PARAMETER s AS CHAR NO-UNDO.
IF NOT SequelLog THEN RETURN.
RUN openStream NO-ERROR.
RUN writeStream(INPUT s) NO-ERROR.
DEF VAR tmpdt AS CHAR NO-UNDO.
ASSIGN tmpdt = 'Error Date = ' + string(YEAR(today),"9999") + string(MONTH(today),"99") + string(DAY(today),"99").
RUN writeStream(INPUT tmpdt) NO-ERROR.
RUN closeStream NO-ERROR.
END PROCEDURE.
/*******************************************************************************
DATA TRANSFER
*******************************************************************************/
DEF VAR hBuffer AS HANDLE NO-UNDO.
DEF VAR hQuery AS HANDLE NO-UNDO.
DEF VAR hBuffld AS HANDLE NO-UNDO.
PROCEDURE MergeTable:
DEFINE INPUT PARAMETER tableName AS CHAR NO-UNDO.
DEFINE INPUT PARAMETER tableKey AS CHAR NO-UNDO.
DEFINE INPUT PARAMETER tableData AS HANDLE NO-UNDO.
DEFINE INPUT PARAMETER deleteOthers AS LOGICAL NO-UNDO.
DEF VAR i AS INT NO-UNDO.
DEF VAR rownum AS INT NO-UNDO.
DEF VAR colnames AS CHAR EXTENT NO-UNDO.
DEF VAR insertStart AS CHAR NO-UNDO.
DEF VAR sqlText AS CHAR FORMAT "X(80)" NO-UNDO.
IF tableData = ? THEN RETURN.
ASSIGN hBuffer = tableData:DEFAULT-BUFFER-HANDLE.
CREATE QUERY hQuery.
hQuery:SET-BUFFERS(hBuffer).
hQuery:QUERY-PREPARE("FOR EACH " + hBuffer:NAME + " NO-LOCK").
hQuery:QUERY-OPEN().
/* first, need to create sql temp table */
/* SequelCon:EXECUTE("CREATE TABLE #" + tableName + " AS (SELECT * FROM " + tableName + " WHERE 1=2)", , ). */
SequelCon:EXECUTE("DROP TABLE #" + tableName, , ) NO-ERROR.
SequelCon:EXECUTE("SELECT * INTO #" + tableName + " FROM [" + tableName + "] WHERE 1 = 2", , ).
insertStart = "INSERT INTO #" + tableName + "(".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
IF i NE 1 THEN insertStart = insertStart + ", ".
hBuffld = hBuffer:BUFFER-FIELD(i).
insertStart = insertStart + "[" + hBuffld:NAME + "]".
END.
insertStart = insertStart + ") VALUES ".
REPEAT:
hQuery:GET-NEXT.
IF hQuery:QUERY-OFF-END THEN LEAVE.
IF rownum = 0 OR rownum MOD {&batchcount} = 0 THEN DO:
/* MESSAGE sqlText. */
IF rownum > 0 THEN DO:
SequelCon:EXECUTE(sqlText, , ) NO-ERROR.
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
/* RUN LogEntry( sqlText ). */
END.
ASSIGN sqlText = insertStart.
END.
IF rownum > 0 AND rownum MOD {&batchcount} > 0 THEN ASSIGN sqlText = sqlText + ", (".
ELSE ASSIGN sqlText = sqlText + "(".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
hBufFld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN sqlText = sqlText + ", ".
IF hBuffld:BUFFER-VALUE EQ ? THEN ASSIGN
sqlText = sqlText + "NULL".
ELSE IF hBuffld:DATA-TYPE = "DATE" OR hBuffld:DATA-TYPE = "CHARACTER" THEN ASSIGN
sqlText = sqlText + "'" + REPLACE(STRING(hBuffld:BUFFER-VALUE), "'", "''") + "'".
ELSE IF hBuffld:DATA-TYPE = "LOGICAL" THEN
DO:
IF LOGICAL(hBuffld:BUFFER-VALUE) THEN ASSIGN sqlText = sqlText + "1".
ELSE ASSIGN sqlText = sqlText + "0".
END.
ELSE ASSIGN sqlText = sqlText + STRING(hBuffld:BUFFER-VALUE).
END.
ASSIGN sqlText = sqlText + ")"
rownum = rownum + 1.
END.
/* do not run if there are no records */
IF rownum > 0 THEN DO:
SequelCon:EXECUTE(sqlText, , ) NO-ERROR.
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
/* RUN LogEntry( sqlText ). */
/* merge... */
sqlText = "MERGE [" + tableName + "] WITH (HOLDLOCK) AS t_old USING (SELECT ".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
ASSIGN hBufFld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN ASSIGN sqlText = sqlText + ", [" + hBuffld:NAME + "]".
ELSE ASSIGN sqlText = sqlText + "[" + hBuffld:NAME + "]".
END.
sqlText = sqlText + " FROM #" + tableName + ") AS t_new ON ".
REPEAT i = 1 TO NUM-ENTRIES(tableKey):
IF i NE 1 THEN ASSIGN sqlText = sqlText + " AND ".
sqlText = sqlText + "t_new." + ENTRY(i,tableKey) + " = t_old." + ENTRY(i,tableKey).
END.
sqlText = sqlText + " WHEN MATCHED THEN UPDATE SET ".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
ASSIGN hBufFld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN ASSIGN sqlText = sqlText + ", ".
ASSIGN sqlText = sqlText + "t_old." + hBuffld:NAME + " = t_new." + hBuffld:NAME.
END.
ASSIGN sqlText = sqlText + " WHEN NOT MATCHED THEN INSERT (".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
ASSIGN hBuffld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN ASSIGN sqlText = sqlText + ", ".
ASSIGN sqlText = sqlText + hBuffld:NAME.
END.
ASSIGN sqlText = sqlText + ") VALUES (".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
ASSIGN hBuffld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN ASSIGN sqlText = sqlText + ", ".
ASSIGN sqlText = sqlText + "t_new." + hBuffld:NAME.
END.
ASSIGN sqlText = sqlText + ");".
SequelCon:EXECUTE(sqlText, , ) NO-ERROR.
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
END.
IF deleteOthers THEN DO:
ASSIGN sqlText = "DELETE [" + tableName + "] FROM [" + tableName + "] LEFT JOIN #" + tableName + " ON ".
REPEAT i = 1 TO NUM-ENTRIES(tableKey):
IF i NE 1 THEN ASSIGN sqlText = sqlText + " AND ".
sqlText = sqlText + tableName + "." + ENTRY(i,tableKey) + " = #" + tableName + "." + ENTRY(i,tableKey).
END.
ASSIGN sqlText = sqlText + " WHERE #" + tableName + "." + ENTRY(1,tableKey) + " IS NULL".
SequelCon:EXECUTE(sqlText, , ) NO-ERROR.
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
/*SequelCon:EXECUTE("DELETE " + tableName + " FROM " + tableName + " LEFT JOIN #" + tableName + " ON " + tableName + "." + tableKey + " = #" + tableName + "." + tableKey + " WHERE #" + tableName + "." + tableKey + " IS NULL", , ).*/
END.
SequelCon:EXECUTE("DROP TABLE #" + tableName, , ) NO-ERROR.
END PROCEDURE.
PROCEDURE UpdateTable:
DEFINE INPUT PARAMETER tableName AS CHAR NO-UNDO.
DEFINE INPUT PARAMETER tableKey AS CHAR NO-UNDO.
DEFINE INPUT PARAMETER tableData AS HANDLE NO-UNDO.
DEF VAR i AS INT NO-UNDO.
DEF VAR rownum AS INT NO-UNDO.
DEF VAR colnames AS CHAR EXTENT NO-UNDO.
DEF VAR insertStart AS CHAR NO-UNDO.
DEF VAR sqlText AS CHAR FORMAT "X(80)" NO-UNDO.
IF tableData = ? THEN RETURN.
ASSIGN hBuffer = tableData:DEFAULT-BUFFER-HANDLE.
CREATE QUERY hQuery.
hQuery:SET-BUFFERS(hBuffer).
hQuery:QUERY-PREPARE("FOR EACH " + hBuffer:NAME + " NO-LOCK").
hQuery:QUERY-OPEN().
/* -- Create SQL Temp Table -- */
SequelCon:EXECUTE("DROP TABLE #" + tableName, , ) NO-ERROR.
SequelCon:EXECUTE("SELECT * INTO #" + tableName + " FROM [" + tableName + "] WHERE 1 = 2", , ).
insertStart = "INSERT INTO #" + tableName + "(".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
IF i NE 1 THEN insertStart = insertStart + ", ".
hBuffld = hBuffer:BUFFER-FIELD(i).
insertStart = insertStart + "[" + hBuffld:NAME + "]".
END.
insertStart = insertStart + ") VALUES ".
REPEAT:
hQuery:GET-NEXT.
IF hQuery:QUERY-OFF-END THEN LEAVE.
IF rownum = 0 OR rownum MOD 20 = 0 THEN DO:
/* MESSAGE sqlText. */
IF rownum > 0 THEN DO:
SequelCon:EXECUTE(sqlText, , ).
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
END.
ASSIGN sqlText = insertStart.
END.
IF rownum > 0 AND rownum MOD 20 > 0 THEN ASSIGN sqlText = sqlText + ", (".
ELSE ASSIGN sqlText = sqlText + "(".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
hBufFld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN sqlText = sqlText + ", ".
IF hBuffld:BUFFER-VALUE EQ ? THEN ASSIGN
sqlText = sqlText + "NULL".
ELSE IF hBuffld:DATA-TYPE = "DATE" OR hBuffld:DATA-TYPE = "CHARACTER" THEN ASSIGN
sqlText = sqlText + "'" + REPLACE(STRING(hBuffld:BUFFER-VALUE), "'", "''") + "'".
ELSE IF hBuffld:DATA-TYPE = "LOGICAL" THEN
DO:
IF LOGICAL(hBuffld:BUFFER-VALUE) THEN ASSIGN sqlText = sqlText + "1".
ELSE ASSIGN sqlText = sqlText + "0".
END.
ELSE ASSIGN sqlText = sqlText + STRING(hBuffld:BUFFER-VALUE).
END.
ASSIGN sqlText = sqlText + ")"
rownum = rownum + 1.
END.
IF rownum = 0 THEN LEAVE. /* do not continue if there are no records */
SequelCon:EXECUTE(sqlText, , ) NO-ERROR.
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
/* -- Update Table -- */
ASSIGN sqlText = "UPDATE t_old".
ASSIGN sqlText = sqlText + " SET ".
REPEAT i = 1 TO hBuffer:NUM-FIELDS:
ASSIGN hBufFld = hBuffer:BUFFER-FIELD(i).
IF i NE 1 THEN ASSIGN sqlText = sqlText + ", ".
ASSIGN sqlText = sqlText + "t_old." + hBuffld:NAME + " = t_new." + hBuffld:NAME.
END.
ASSIGN sqlText = sqlText + " FROM [" + tableName + "] AS t_old, #" + tableName + " AS t_new".
ASSIGN sqlText = sqlText + " WHERE ".
REPEAT i = 1 TO NUM-ENTRIES(tableKey):
IF i NE 1 THEN ASSIGN sqlText = sqlText + " AND ".
sqlText = sqlText + "t_new." + ENTRY(i,tableKey) + " = t_old." + ENTRY(i,tableKey).
END.
ASSIGN sqlText = sqlText + ";".
SequelCon:EXECUTE(sqlText, , ) NO-ERROR.
IF ERROR-STATUS:NUM-MESSAGES > 0 THEN DO:
RUN LogEntry( ERROR-STATUS:GET-MESSAGE(1) + CHR(10) + sqlText ).
END.
END PROCEDURE.