sqldbtoolsunit.pas 26 KB

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