1 unit SQLDBToolsUnit;
2
3 {$mode objfpc}{$H+}
4
5 interface
6
7 uses
8 Classes, SysUtils, toolsunit
9 ,db, sqldb
10 ,mysql40conn, mysql41conn, mysql50conn, mysql51conn, mysql55conn, mysql56conn, mysql57conn, mysql80conn
11 ,ibconnection
12 ,pqconnection
13 ,odbcconn
14 {$IFNDEF WIN64}
15 {See packages\fcl-db\fpmake.pp: Oracle connector not built yet on Win64}
16 ,oracleconnection
17 {$ENDIF WIN64}
18 ,sqlite3conn
19 ,mssqlconn
20 ;
21
22 type
23 TSQLConnType = (mysql40,mysql41,mysql50,mysql51,mysql55,mysql56,mysql57,mysql80,postgresql,interbase,odbc,oracle,sqlite3,mssql,sybase);
24 TSQLServerType = (ssFirebird, ssInterbase, ssMSSQL, ssMySQL, ssOracle, ssPostgreSQL, ssSQLite, ssSybase, ssUnknown);
25
26 const
27 MySQLConnTypes = [mysql40,mysql41,mysql50,mysql51,mysql55,mysql56,mysql57,mysql80];
28 SQLConnTypesNames : Array [TSQLConnType] of String[19] =
29 ('MYSQL40','MYSQL41','MYSQL50','MYSQL51','MYSQL55','MYSQL56','MYSQL57','MYSQL80','POSTGRESQL','INTERBASE','ODBC','ORACLE','SQLITE3','MSSQL','SYBASE');
30
31 STestNotApplicable = 'This test does not apply to this sqldb connection type';
32
33
34 type
35 { TSQLDBConnector }
36 TSQLDBConnector = class(TDBConnector)
37 private
38 FConnection : TSQLConnection;
39 FTransaction : TSQLTransaction;
40 FQuery : TSQLQuery;
41 FUniDirectional: boolean;
42 procedure CreateFConnection;
CreateQuerynull43 Function CreateQuery : TSQLQuery;
44 protected
45 procedure SetTestUniDirectional(const AValue: boolean); override;
GetTestUniDirectionalnull46 function GetTestUniDirectional: boolean; override;
47 procedure CreateNDatasets; override;
48 procedure CreateFieldDataset; override;
49 // If logging is enabled, this procedure will receive the event
50 // from the SQLDB logging system
51 // For custom logging call with sender nil and eventtype detCustom
52 procedure DoLogEvent(Sender: TSQLConnection; EventType: TDBEventType; Const Msg : String);
53 procedure DropNDatasets; override;
54 procedure DropFieldDataset; override;
InternalGetNDatasetnull55 Function InternalGetNDataset(n : integer) : TDataset; override;
InternalGetFieldDatasetnull56 Function InternalGetFieldDataset : TDataSet; override;
57 public
58 procedure TryDropIfExist(ATableName : String);
59 procedure TryCreateSequence(ASequenceName : String);
60 procedure TryDropSequence(ASequenceName: String);
61 destructor Destroy; override;
62 constructor Create; override;
63 procedure ExecuteDirect(const SQL: string);
64 // Issue a commit(retaining) for databases that need it (e.g. in DDL)
65 procedure CommitDDL;
66 Procedure FreeTransaction;
67 property Connection : TSQLConnection read FConnection;
68 property Transaction : TSQLTransaction read FTransaction;
69 property Query : TSQLQuery read FQuery;
70 end;
71
72 var SQLConnType : TSQLConnType;
73 SQLServerType : TSQLServerType;
74 FieldtypeDefinitions : Array [TFieldType] of String[20];
75
IdentifierCasenull76 function IdentifierCase(const s: string): string;
77
78 implementation
79
80 uses StrUtils;
81
82 type
83 TSQLServerTypesMapItem = record
84 s: string;
85 t: TSQLServerType;
86 end;
87
88 const
89 FieldtypeDefinitionsConst : Array [TFieldType] of String[20] =
90 (
91 {ftUnknown} '',
92 {ftString} 'VARCHAR(10)',
93 {ftSmallint} 'SMALLINT',
94 {ftInteger} 'INTEGER',
95 {ftWord} '',
96 {ftBoolean} 'BOOLEAN',
97 {ftFloat} 'DOUBLE PRECISION',
98 {ftCurrency} '',
99 {ftBCD} 'DECIMAL(18,4)',
100 {ftDate} 'DATE',
101 {ftTime} 'TIME',
102 {ftDateTime} 'TIMESTAMP',
103 {ftBytes} '',
104 {ftVarBytes} '',
105 {ftAutoInc} '',
106 {ftBlob} 'BLOB',
107 {ftMemo} 'BLOB',
108 {ftGraphic} 'BLOB',
109 {ftFmtMemo} '',
110 {ftParadoxOle} '',
111 {ftDBaseOle} '',
112 {ftTypedBinary} '',
113 {ftCursor} '',
114 {ftFixedChar} 'CHAR(10)',
115 {ftWideString} '',
116 {ftLargeint} 'BIGINT',
117 {ftADT} '',
118 {ftArray} '',
119 {ftReference} '',
120 {ftDataSet} '',
121 {ftOraBlob} '',
122 {ftOraClob} '',
123 {ftVariant} '',
124 {ftInterface} '',
125 {ftIDispatch} '',
126 {ftGuid} '',
127 {ftTimeStamp} 'TIMESTAMP',
128 {ftFMTBcd} 'NUMERIC(18,6)',
129 {ftFixedWideChar} '',
130 {ftWideMemo} ''
131 );
132
133 // names as returned by ODBC SQLGetInfo(..., SQL_DBMS_NAME, ...) and GetConnectionInfo(citServerType)
134 SQLServerTypesMap : array [0..7] of TSQLServerTypesMapItem = (
135 (s: 'Firebird'; t: ssFirebird),
136 (s: 'Interbase'; t: ssInterbase),
137 (s: 'Microsoft SQL Server'; t: ssMSSQL),
138 (s: 'MySQL'; t: ssMySQL),
139 (s: 'Oracle'; t: ssOracle),
140 (s: 'PostgreSQL'; t: ssPostgreSQL),
141 (s: 'SQLite3'; t: ssSQLite),
142 (s: 'ASE'; t: ssSybase)
143 );
144
145 // fall back mapping (e.g. in case GetConnectionInfo(citServerType) is not implemented)
146 SQLConnTypeToServerTypeMap : array[TSQLConnType] of TSQLServerType =
147 (ssMySQL,ssMySQL,ssMySQL,ssMySQL,ssMySQL,ssMySQL,ssMySQL,ssPostgreSQL,ssFirebird,ssUnknown,ssOracle,ssSQLite,ssMSSQL,ssSybase);
148
149
IdentifierCasenull150 function IdentifierCase(const s: string): string;
151 begin
152 // format unquoted identifier name as required by SQL servers
153 case SQLServerType of
154 ssPostgreSQL: Result := LowerCase(s); // PostgreSQL stores unquoted identifiers in lowercase (incompatible with the SQL standard)
155 ssInterbase,
156 ssFirebird : Result := UpperCase(s); // Dialect 1 requires uppercase; dialect 3 is case agnostic
157 else
158 Result := s; // mixed case
159 end;
160 end;
161
162 { TSQLDBConnector }
163
164 procedure TSQLDBConnector.CreateFConnection;
165 var t : TSQLConnType;
166 i : integer;
167 s : string;
168 begin
169 for t := low(SQLConnTypesNames) to high(SQLConnTypesNames) do
170 if UpperCase(dbconnectorparams) = SQLConnTypesNames[t] then SQLConnType := t;
171
172 case SQLConnType of
173 MYSQL40: Fconnection := TMySQL40Connection.Create(nil);
174 MYSQL41: Fconnection := TMySQL41Connection.Create(nil);
175 MYSQL50: Fconnection := TMySQL50Connection.Create(nil);
176 MYSQL51: Fconnection := TMySQL51Connection.Create(nil);
177 MYSQL55: Fconnection := TMySQL55Connection.Create(nil);
178 MYSQL56: Fconnection := TMySQL56Connection.Create(nil);
179 MYSQL57: Fconnection := TMySQL57Connection.Create(nil);
180 MYSQL80: Fconnection := TMySQL80Connection.Create(nil);
181 SQLITE3: Fconnection := TSQLite3Connection.Create(nil);
182 POSTGRESQL: Fconnection := TPQConnection.Create(nil);
183 INTERBASE : Fconnection := TIBConnection.Create(nil);
184 ODBC: Fconnection := TODBCConnection.Create(nil);
185 {$IFNDEF Win64}
186 ORACLE: Fconnection := TOracleConnection.Create(nil);
187 {$ENDIF Win64}
188 MSSQL: Fconnection := TMSSQLConnection.Create(nil);
189 SYBASE: Fconnection := TSybaseConnection.Create(nil);
190 else writeln('Invalid database type, check if a valid database type for your achitecture was provided in the file ''database.ini''');
191 end;
192
193 FTransaction := TSQLTransaction.Create(nil);
194
195 with Fconnection do
196 begin
197 Transaction := FTransaction;
198 DatabaseName := dbname;
199 UserName := dbuser;
200 Password := dbpassword;
201 HostName := dbhostname;
202 CharSet := dbcharset;
203 if dblogfilename<>'' then
204 begin
205 LogEvents:=[detCustom,detCommit,detExecute,detRollBack];
206 OnLog:=@DoLogEvent;
207 end;
208
209 if (dbhostname='') and (SQLConnType=interbase) then
210 begin
211 // Firebird embedded: create database file if it doesn't yet exist
212 // Note: pagesize parameter has influence on behavior. We're using
213 // Firebird default here.
214 if not(fileexists(dbname)) then
215 CreateDB; //Create testdb
216 end;
217
218 if length(dbQuoteChars)>1 then
219 FieldNameQuoteChars:=dbQuoteChars;
220
221 Open;
222 end;
223
224 // determine remote SQL Server to which we are connected
225 s := Fconnection.GetConnectionInfo(citServerType);
226 if s = '' then
227 SQLServerType := SQLConnTypeToServerTypeMap[SQLConnType] // if citServerType isn't implemented
228 else
229 for i := low(SQLServerTypesMap) to high(SQLServerTypesMap) do
230 if SQLServerTypesMap[i].s = s then
231 SQLServerType := SQLServerTypesMap[i].t;
232
233 FieldtypeDefinitions := FieldtypeDefinitionsConst;
234
235 // Server-specific initialization
236 case SQLServerType of
237 ssFirebird:
238 begin
239 // Firebird < 3.0 has no support for Boolean data type:
240 FieldtypeDefinitions[ftBoolean] := '';
241 FieldtypeDefinitions[ftMemo] := 'BLOB SUB_TYPE TEXT';
242 end;
243 ssInterbase:
244 begin
245 FieldtypeDefinitions[ftMemo] := 'BLOB SUB_TYPE TEXT';
246 FieldtypeDefinitions[ftLargeInt] := 'NUMERIC(18,0)';
247 end;
248 ssMSSQL, ssSybase:
249 // todo: Sybase: copied over MSSQL; verify correctness
250 // note: test database should have case-insensitive collation
251 begin
252 FieldtypeDefinitions[ftBoolean] := 'BIT';
253 FieldtypeDefinitions[ftFloat] := 'FLOAT';
254 FieldtypeDefinitions[ftCurrency]:= 'MONEY';
255 FieldtypeDefinitions[ftDateTime]:= 'DATETIME';
256 FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
257 FieldtypeDefinitions[ftVarBytes]:= 'VARBINARY(10)';
258 FieldtypeDefinitions[ftBlob] := 'IMAGE';
259 FieldtypeDefinitions[ftMemo] := 'TEXT';
260 FieldtypeDefinitions[ftGraphic] := '';
261 FieldtypeDefinitions[ftGuid] := 'UNIQUEIDENTIFIER';
262 FieldtypeDefinitions[ftWideString] := 'NVARCHAR(10)';
263 FieldtypeDefinitions[ftFixedWideChar] := 'NCHAR(10)';
264 //FieldtypeDefinitions[ftWideMemo] := 'NTEXT'; // Sybase has UNITEXT?
265
266 // Proper blob support:
267 FConnection.ExecuteDirect('SET TEXTSIZE 2147483647');
268 if SQLServerType=ssMSSQL then
269 begin
270 // When running CREATE TABLE statements, allow NULLs by default - without
271 // having to specify NULL all the time:
272 // http://msdn.microsoft.com/en-us/library/ms174979.aspx
273 //
274 // Padding character fields is expected by ANSI and sqldb, as well as
275 // recommended by Microsoft:
276 // http://msdn.microsoft.com/en-us/library/ms187403.aspx
277 FConnection.ExecuteDirect('SET ANSI_NULL_DFLT_ON ON; SET ANSI_PADDING ON; SET ANSI_WARNINGS OFF');
278 end;
279 if SQLServerType=ssSybase then
280 begin
281 // Evaluate NULL expressions according to ANSI SQL:
282 // http://infocenter.sybase.com/archive/index.jsp?topic=/com.sybase.help.ase_15.0.commands/html/commands/commands85.htm
283 FConnection.ExecuteDirect('SET ANSINULL ON');
284
285 { Tests require these database options set
286 1) with ddl in tran; e.g.
287 use master
288 go
289 sp_dboption pubs3, 'ddl in tran', true
290 go
291 Avoid errors like
292 The 'CREATE TABLE' command is not allowed within a multi-statement transaction in the 'test' database.
293 2) allow nulls by default, e.g.
294 use master
295 go
296 sp_dboption pubs3, 'allow nulls by default', true
297 go
298 }
299 end;
300 FTransaction.Commit;
301 end;
302 ssMySQL:
303 begin
304 FieldtypeDefinitions[ftWord] := 'SMALLINT UNSIGNED';
305 // MySQL recognizes BOOLEAN, but as synonym for TINYINT, not true sql boolean datatype
306 FieldtypeDefinitions[ftBoolean] := '';
307 // Use 'DATETIME' for datetime fields instead of timestamp, because
308 // mysql's timestamps are only valid in the range 1970-2038.
309 // Downside is that fields defined as 'TIMESTAMP' aren't tested
310 FieldtypeDefinitions[ftDateTime] := 'DATETIME';
311 FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
312 FieldtypeDefinitions[ftVarBytes] := 'VARBINARY(10)';
313 FieldtypeDefinitions[ftMemo] := 'TEXT';
314 // Add into my.ini: sql-mode="...,PAD_CHAR_TO_FULL_LENGTH,ANSI_QUOTES" or set it explicitly by:
315 // PAD_CHAR_TO_FULL_LENGTH to avoid trimming trailing spaces contrary to SQL standard (MySQL 5.1.20+)
316 FConnection.ExecuteDirect('SET SESSION sql_mode=''STRICT_ALL_TABLES,PAD_CHAR_TO_FULL_LENGTH,ANSI_QUOTES''');
317 FTransaction.Commit;
318 end;
319 ssOracle:
320 begin
321 FieldtypeDefinitions[ftBoolean] := '';
322 // At least Oracle 10, 11 do not support a BIGINT field:
323 FieldtypeDefinitions[ftLargeInt] := 'NUMBER(19,0)';
324 FieldtypeDefinitions[ftTime] := 'TIMESTAMP';
325 FieldtypeDefinitions[ftMemo] := 'CLOB';
326 FieldtypeDefinitions[ftWideString] := 'NVARCHAR2(10)';
327 FieldtypeDefinitions[ftFixedWideChar] := 'NCHAR(10)';
328 FieldtypeDefinitions[ftWideMemo] := 'NCLOB';
329 end;
330 ssPostgreSQL:
331 begin
332 FieldtypeDefinitions[ftCurrency] := 'MONEY'; // ODBC?!
333 FieldtypeDefinitions[ftBlob] := 'BYTEA';
334 FieldtypeDefinitions[ftMemo] := 'TEXT';
335 FieldtypeDefinitions[ftGraphic] := '';
336 FieldtypeDefinitions[ftGuid] := 'UUID';
337 end;
338 ssSQLite:
339 begin
340 // SQLite stores all values with decimal point as 8 byte (double) IEEE floating point numbers
341 // (it causes that some tests (for BCD, FmtBCD fields) fails for exact numeric values, which can't be lossless expressed as 8 byte floating point values)
342 FieldtypeDefinitions[ftWord] := 'WORD';
343 FieldtypeDefinitions[ftCurrency] := 'CURRENCY';
344 FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
345 FieldtypeDefinitions[ftVarBytes] := 'VARBINARY(10)';
346 FieldtypeDefinitions[ftMemo] := 'CLOB'; //or TEXT SQLite supports both, but CLOB is sql standard (TEXT not)
347 FieldtypeDefinitions[ftWideString] := 'NVARCHAR(10)';
348 FieldtypeDefinitions[ftFixedWideChar] := 'NCHAR(10)';
349 FieldtypeDefinitions[ftWideMemo] := 'NCLOB';
350 end;
351 end;
352
353 if SQLConnType in [mysql40,mysql41] then
354 begin
355 // Mysql versions prior to 5.0.3 removes the trailing spaces on varchar
356 // fields on insertion. So to test properly, we have to do the same
357 for i := 0 to testValuesCount-1 do
358 testStringValues[i] := TrimRight(testStringValues[i]);
359 end;
360
361 if SQLServerType in [ssMSSQL, ssSQLite, ssSybase] then
362 // Some DB's do not support sql compliant boolean data type.
363 for i := 0 to testValuesCount-1 do
364 testValues[ftBoolean, i] := BoolToStr(testBooleanValues[i], '1', '0');
365
366 if SQLServerType in [ssMySQL] then
367 begin
368 // Some DB's do not support milliseconds in datetime and time fields.
369 for i := 0 to testValuesCount-1 do
370 begin
371 testTimeValues[i] := copy(testTimeValues[i],1,8)+'.000';
372 testValues[ftTime,i] := copy(testTimeValues[i],1,8)+'.000';
373 if length(testValues[ftDateTime,i]) > 19 then
374 testValues[ftDateTime,i] := copy(testValues[ftDateTime,i],1,19)+'.000';
375 end;
376 end;
377
378 if SQLServerType in [ssFirebird, ssInterbase, ssMSSQL, ssOracle, ssPostgreSQL, ssSybase] then
379 begin
380 // Some db's do not support times > 24:00:00
381 testTimeValues[3]:='13:25:15.000';
382 testValues[ftTime,3]:='13:25:15.000';
383 if SQLServerType in [ssFirebird, ssInterbase, ssMSSQL, ssOracle] then
384 begin
385 // Firebird, Oracle, MS SQL Server do not support time = 24:00:00
386 // MS SQL Server "datetime" supports only time up to 23:59:59.997
387 testTimeValues[2]:='23:59:59.997';
388 testValues[ftTime,2]:='23:59:59.997';
389 end;
390 end;
391
392 if SQLServerType in [ssMSSQL, ssSybase] then
393 // Some DB's do not support datetime values before 1753-01-01
394 for i := 18 to testValuesCount-1 do
395 testValues[ftDateTime,i] := testValues[ftDateTime,0];
396
397 // DecimalSeparator must correspond to monetary locale (lc_monetary) set on PostgreSQL server
398 // Here we assume, that locale on client side is same as locale on server
399 if SQLServerType in [ssPostgreSQL] then
400 for i := 0 to testValuesCount-1 do
401 testValues[ftCurrency,i] := QuotedStr(CurrToStr(testCurrencyValues[i]));
402
403 // SQLite does not support fixed length CHAR datatype
404 if SQLServerType in [ssSQLite] then
405 for i := 0 to testValuesCount-1 do
406 testValues[ftFixedChar,i] := PadRight(testValues[ftFixedChar,i], 10);
407 end;
408
TSQLDBConnector.CreateQuerynull409 Function TSQLDBConnector.CreateQuery: TSQLQuery;
410
411 begin
412 Result := TSQLQuery.create(nil);
413 with Result do
414 begin
415 database := Fconnection;
416 transaction := Ftransaction;
417 PacketRecords := -1; // To avoid: "Connection is busy with results for another hstmt" (ODBC,MSSQL)
418 end;
419 end;
420
421
422
423 procedure TSQLDBConnector.SetTestUniDirectional(const AValue: boolean);
424 begin
425 FUniDirectional:=avalue;
426 FQuery.UniDirectional:=AValue;
427 end;
428
GetTestUniDirectionalnull429 function TSQLDBConnector.GetTestUniDirectional: boolean;
430 begin
431 result := FUniDirectional;
432 end;
433
434 procedure TSQLDBConnector.CreateNDatasets;
435 var CountID : Integer;
436 begin
437 try
438 Ftransaction.StartTransaction;
439 TryDropIfExist('FPDEV');
440 Fconnection.ExecuteDirect('create table FPDEV (' +
441 ' ID INT NOT NULL, ' +
442 ' NAME VARCHAR(50), ' +
443 ' PRIMARY KEY (ID) ' +
444 ')');
445
446 FTransaction.CommitRetaining;
447
448 for countID := 1 to MaxDataSet do
449 Fconnection.ExecuteDirect('insert into FPDEV (ID,NAME) ' +
450 'values ('+inttostr(countID)+',''TestName'+inttostr(countID)+''')');
451
452 Ftransaction.Commit;
453 except
454 on E: Exception do begin
455 if dblogfilename<>'' then
456 DoLogEvent(nil,detCustom,'Exception running CreateNDatasets: '+E.Message);
457 if Ftransaction.Active then
458 Ftransaction.Rollback
459 end;
460 end;
461 end;
462
463 procedure TSQLDBConnector.CreateFieldDataset;
464 var
465 CountID : Integer;
466 FType : TFieldType;
467 Sql,sql1: String;
468
String2Hexnull469 function String2Hex(Source: string): string;
470 // Converts ASCII codes into hex
471 var
472 i: integer;
473 begin
474 result := '';
475 for i := 1 to length(Source) do
476 result := result + inttohex(ord(Source[i]),2);
477 end;
478
479 begin
480 try
481 Ftransaction.StartTransaction;
482 TryDropIfExist('FPDEV_FIELD');
483
484 Sql := 'create table FPDEV_FIELD (ID INT NOT NULL,';
485 for FType := low(TFieldType)to high(TFieldType) do
486 if FieldtypeDefinitions[FType]<>'' then
487 sql := sql + 'F' + Fieldtypenames[FType] + ' ' +
488 FieldtypeDefinitions[FType] + ',';
489 Sql := Sql + 'PRIMARY KEY (ID))';
490
491 FConnection.ExecuteDirect(Sql);
492
493 FTransaction.CommitRetaining;
494
495 for countID := 0 to testValuesCount-1 do
496 begin
497 Sql := 'insert into FPDEV_FIELD (ID';
498 Sql1 := 'values ('+IntToStr(countID);
499 for FType := low(TFieldType)to high(TFieldType) do
500 if FieldtypeDefinitions[FType]<>'' then
501 begin
502 sql := sql + ',F' + Fieldtypenames[FType];
503 if testValues[FType,CountID] <> '' then
504 if FType in [ftBoolean, ftCurrency] then
505 sql1 := sql1 + ',' + testValues[FType,CountID]
506 else if (FType in [ftBlob, ftBytes, ftGraphic, ftVarBytes]) and
507 (SQLServerType = ssOracle) then
508 // Oracle does not accept string literals in blob insert statements
509 // convert 'DEADBEEF' hex literal to binary:
510 sql1 := sql1 + ', HEXTORAW(' + QuotedStr(String2Hex(testValues[FType,CountID])) + ') '
511 else if (FType = ftDate) and
512 (SQLServerType = ssOracle) then
513 // Oracle requires date conversion; otherwise
514 // ORA-01861: literal does not match format string
515 // ANSI/ISO date literal:
516 sql1 := sql1 + ', DATE ' + QuotedStr(testValues[FType,CountID])
517 else if (FType = ftDateTime) and
518 (SQLServerType = ssOracle) then begin
519 // similar to ftDate handling
520 // Could be a real date+time or only date. Does not consider only time.
521 if pos(' ',testValues[FType,CountID])>0 then
522 sql1 := sql1 + ', TIMESTAMP ' + QuotedStr(testValues[FType,CountID])
523 else
524 sql1 := sql1 + ', DATE ' + QuotedStr(testValues[FType,CountID]);
525 end
526 else if (FType = ftTime) and
527 (SQLServerType = ssOracle) then
528 // similar to ftDate handling
529 // More or less arbitrary default time; there is no time-only data type in Oracle.
530 sql1 := sql1 + ', TIMESTAMP ' + QuotedStr('0001-01-01 '+testValues[FType,CountID])
531 else
532 sql1 := sql1 + ',' + QuotedStr(testValues[FType,CountID])
533 else
534 sql1 := sql1 + ',NULL';
535 end;
536 Sql := sql + ')';
537 Sql1 := sql1+ ')';
538
539 Fconnection.ExecuteDirect(sql + ' ' + sql1);
540 end;
541
542 Ftransaction.Commit;
543 except
544 on E: Exception do begin
545 if dblogfilename<>'' then
546 DoLogEvent(nil,detCustom,'Exception running CreateFieldDataset: '+E.Message);
547 if Ftransaction.Active then Ftransaction.Rollback;
548 end;
549 end;
550 end;
551
552 procedure TSQLDBConnector.DoLogEvent(Sender: TSQLConnection;
553 EventType: TDBEventType; Const Msg: String);
554 var
555 Category: string;
556 begin
557 case EventType of
558 detCustom: Category:='Custom';
559 detPrepare: Category:='Prepare';
560 detExecute: Category:='Execute';
561 detFetch: Category:='Fetch';
562 detCommit: Category:='Commit';
563 detRollBack: Category:='Rollback';
564 else Category:='Unknown event. Please fix program code.';
565 end;
566 LogMessage(Category,Msg);
567 end;
568
569 procedure TSQLDBConnector.DropNDatasets;
570 begin
571 if assigned(FTransaction) then
572 begin
573 try
574 if Ftransaction.Active then Ftransaction.Rollback;
575 Ftransaction.StartTransaction;
576 Fconnection.ExecuteDirect('DROP TABLE FPDEV');
577 Ftransaction.Commit;
578 Except
579 on E: Exception do begin
580 if dblogfilename<>'' then
581 DoLogEvent(nil,detCustom,'Exception running DropNDatasets: '+E.Message);
582 if Ftransaction.Active then Ftransaction.Rollback
583 end;
584 end;
585 end;
586 end;
587
588 procedure TSQLDBConnector.DropFieldDataset;
589 begin
590 if assigned(FTransaction) then
591 begin
592 try
593 if Ftransaction.Active then Ftransaction.Rollback;
594 Ftransaction.StartTransaction;
595 Fconnection.ExecuteDirect('DROP TABLE FPDEV_FIELD');
596 Ftransaction.Commit;
597 Except
598 on E: Exception do begin
599 if dblogfilename<>'' then
600 DoLogEvent(nil,detCustom,'Exception running DropFieldDataset: '+E.Message);
601 if Ftransaction.Active then Ftransaction.Rollback
602 end;
603 end;
604 end;
605 end;
606
TSQLDBConnector.InternalGetNDatasetnull607 Function TSQLDBConnector.InternalGetNDataset(n: integer): TDataset;
608 begin
609 Result := CreateQuery;
610 with (Result as TSQLQuery) do
611 begin
612 sql.clear;
613 sql.add('SELECT * FROM FPDEV WHERE ID < '+inttostr(n+1)+' ORDER BY ID');
614 UniDirectional:=TestUniDirectional;
615 end;
616 end;
617
TSQLDBConnector.InternalGetFieldDatasetnull618 Function TSQLDBConnector.InternalGetFieldDataset: TDataSet;
619 begin
620 Result := CreateQuery;
621 with (Result as TSQLQuery) do
622 begin
623 sql.clear;
624 sql.add('SELECT * FROM FPDEV_FIELD');
625 UniDirectional:=TestUniDirectional;
626 end;
627 end;
628
629 procedure TSQLDBConnector.TryDropIfExist(ATableName: String);
630 begin
631 // This makes life so much easier, since it avoids the exception if the table already
632 // exists. And while this exception is in a try..except statement, the debugger
633 // always shows the exception, which is pretty annoying.
634 try
635 case SQLServerType of
636 ssFirebird:
637 begin
638 // This only works with Firebird 2+
639 FConnection.ExecuteDirect('execute block as begin if (exists (select 1 from rdb$relations where upper(rdb$relation_name)=''' + UpperCase(ATableName) + ''')) '+
640 'then execute statement ''drop table ' + ATableName + ';'';end');
641 FTransaction.CommitRetaining;
642 end;
643 ssMSSQL:
644 begin
645 // Checking is needed here to avoid getting "auto rollback" of a subsequent CREATE TABLE statement
646 // which leads to the rollback not referring to the right transaction=>SQL error
647 // Use SQL92 ISO standard INFORMATION_SCHEMA:
648 FConnection.ExecuteDirect(
649 'if exists (select * from INFORMATION_SCHEMA.TABLES where TABLE_TYPE=''BASE TABLE'' AND TABLE_NAME=''' + ATableName + ''')'+
650 ' drop table ' + ATableName );
651 end;
652 ssMySQL:
653 begin
654 FConnection.ExecuteDirect('drop table if exists ' + ATableName);
655 end;
656 ssPostgreSQL,
657 ssSQLite:
658 begin
659 FConnection.ExecuteDirect('drop table if exists ' + ATableName);
660 FTransaction.CommitRetaining;
661 end;
662 ssOracle:
663 begin
664 FConnection.ExecuteDirect(
665 'declare ' +
666 ' c int; ' +
667 'begin ' +
668 ' select count(*) into c from all_tables where table_name = upper(''' + ATableName + '''); ' +
669 ' if c = 1 then ' +
670 ' execute immediate ''drop table ' + ATableName + '''; ' +
671 ' end if; ' +
672 'end; ');
673 end;
674 ssSybase:
675 begin
676 // Checking is needed here to avoid getting "auto rollback" of a subsequent CREATE TABLE statement
677 // which leads to the rollback not referring to the right transaction=>SQL error
678 // Can't use SQL standard information_schema; instead query sysobjects for User tables
679 FConnection.ExecuteDirect(
680 'if exists (select * from sysobjects where type = ''U'' and name=''' + ATableName + ''') '+
681 'begin '+
682 'drop table ' + ATableName + ' '+
683 'end');
684 end;
685 end;
686 except
687 FTransaction.RollbackRetaining;
688 end;
689 end;
690
691 procedure TSQLDBConnector.TryDropSequence(ASequenceName: String);
692
693 var
694 NoSeq : Boolean;
695
696 begin
697 NoSeq:=False;
698 try
699 case SQLServerType of
700 ssInterbase,
701 ssFirebird: FConnection.ExecuteDirect('DROP GENERATOR '+ASequenceName);
702 ssOracle,
703 ssPostgreSQL,
704 ssSybase,
705 ssMSSQL : FConnection.ExecuteDirect('DROP SEQUENCE '+ASequenceName+' START WITH 1 INCREMENT BY 1');
706 ssSQLite : FConnection.ExecuteDirect('delete from sqlite_sequence where (name='''+ASequenceName+''')');
707 else
708 NoSeq:=True;
709 end;
710 except
711 FTransaction.RollbackRetaining;
712 end;
713 if NoSeq then
714 Raise EDatabaseError.Create('Engine does not support sequences');
715 end;
716
717 procedure TSQLDBConnector.TryCreateSequence(ASequenceName: String);
718
719 var
720 NoSeq : Boolean;
721
722 begin
723 NoSeq:=False;
724 case SQLServerType of
725 ssInterbase,
726 ssFirebird: FConnection.ExecuteDirect('CREATE GENERATOR '+ASequenceName);
727 ssOracle,
728 ssPostgreSQL,
729 ssSybase,
730 ssMSSQL : FConnection.ExecuteDirect('CREATE SEQUENCE '+ASequenceName+' START WITH 1 INCREMENT BY 1');
731 ssSQLite : FConnection.ExecuteDirect('insert into sqlite_sequence (name,seq) values ('''+ASequenceName+''',1)');
732 else
733 Raise EDatabaseError.Create('Engine does not support sequences');
734 end;
735 end;
736
737
738 procedure TSQLDBConnector.ExecuteDirect(const SQL: string);
739 begin
740 Connection.ExecuteDirect(SQL);
741 end;
742
743 procedure TSQLDBConnector.CommitDDL;
744 begin
745 // Commits schema definition and manipulation statements;
746 // Firebird/Interbase need a commit after a DDL statement. Not necessary for the other connections
747 if SQLServerType in [ssFirebird, ssInterbase] then
748 Transaction.CommitRetaining;
749 end;
750
751 Procedure TSQLDBConnector.FreeTransaction;
752 begin
753 FreeAndNil(FTransaction);
754 end;
755
756 destructor TSQLDBConnector.Destroy;
757 begin
758 FreeAndNil(FQuery);
759 if assigned(FTransaction) then
760 begin
761 try
762 if not (stoUseImplicit in Transaction.Options) then
763 begin
764 if Ftransaction.Active then
765 Ftransaction.Rollback;
766 Ftransaction.StartTransaction;
767 end;
768 TryDropIfExist('FPDEV2');
769 if not (stoUseImplicit in Transaction.Options) then
770 Ftransaction.Commit;
771 Except
772 if Ftransaction.Active and not (stoUseImplicit in Transaction.Options) then
773 Ftransaction.Rollback;
774 end; // try
775 end;
776 FreeTransaction;
777 FreeAndNil(FConnection);
778 inherited Destroy;
779 end;
780
781 constructor TSQLDBConnector.Create;
782 begin
783 FConnection := nil;
784 CreateFConnection;
785 FQuery := CreateQuery;
786 Inherited;
787 end;
788
789 initialization
790 RegisterClass(TSQLDBConnector);
791 end.
792
793