sqldbtoolsunit.pas 27 KB

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