sqldbtoolsunit.pas 26 KB

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