sqldbtoolsunit.pas 27 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799
  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, mysql80conn
  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,mysql80,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,mysql80];
  23. SQLConnTypesNames : Array [TSQLConnType] of String[19] =
  24. ('MYSQL40','MYSQL41','MYSQL50','MYSQL51','MYSQL55','MYSQL56','MYSQL57','MYSQL80','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,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. MYSQL80: Fconnection := TMySQL80Connection.Create(nil);
  166. SQLITE3: Fconnection := TSQLite3Connection.Create(nil);
  167. POSTGRESQL: Fconnection := TPQConnection.Create(nil);
  168. INTERBASE : Fconnection := TIBConnection.Create(nil);
  169. ODBC: Fconnection := TODBCConnection.Create(nil);
  170. {$IFNDEF Win64}
  171. ORACLE: Fconnection := TOracleConnection.Create(nil);
  172. {$ENDIF Win64}
  173. MSSQL: Fconnection := TMSSQLConnection.Create(nil);
  174. SYBASE: Fconnection := TSybaseConnection.Create(nil);
  175. else writeln('Invalid database type, check if a valid database type for your achitecture was provided in the file ''database.ini''');
  176. end;
  177. FTransaction := TSQLTransaction.Create(nil);
  178. with Fconnection do
  179. begin
  180. Transaction := FTransaction;
  181. DatabaseName := dbname;
  182. UserName := dbuser;
  183. Password := dbpassword;
  184. HostName := dbhostname;
  185. CharSet := dbcharset;
  186. if dblogfilename<>'' then
  187. begin
  188. LogEvents:=[detCustom,detCommit,detExecute,detRollBack];
  189. OnLog:=@DoLogEvent;
  190. end;
  191. if (dbhostname='') and (SQLConnType=interbase) then
  192. begin
  193. // Firebird embedded: create database file if it doesn't yet exist
  194. // Note: pagesize parameter has influence on behavior. We're using
  195. // Firebird default here.
  196. if not(fileexists(dbname)) then
  197. CreateDB; //Create testdb
  198. end;
  199. if length(dbQuoteChars)>1 then
  200. FieldNameQuoteChars:=dbQuoteChars;
  201. Open;
  202. end;
  203. // determine remote SQL Server to which we are connected
  204. s := Fconnection.GetConnectionInfo(citServerType);
  205. if s = '' then
  206. SQLServerType := SQLConnTypeToServerTypeMap[SQLConnType] // if citServerType isn't implemented
  207. else
  208. for i := low(SQLServerTypesMap) to high(SQLServerTypesMap) do
  209. if SQLServerTypesMap[i].s = s then
  210. SQLServerType := SQLServerTypesMap[i].t;
  211. FieldtypeDefinitions := FieldtypeDefinitionsConst;
  212. // Server-specific initialization
  213. case SQLServerType of
  214. ssFirebird:
  215. begin
  216. // Firebird < 3.0 has no support for Boolean data type:
  217. FieldtypeDefinitions[ftBoolean] := '';
  218. FieldtypeDefinitions[ftMemo] := 'BLOB SUB_TYPE TEXT';
  219. end;
  220. ssInterbase:
  221. begin
  222. FieldtypeDefinitions[ftMemo] := 'BLOB SUB_TYPE TEXT';
  223. FieldtypeDefinitions[ftLargeInt] := 'NUMERIC(18,0)';
  224. end;
  225. ssMSSQL, ssSybase:
  226. // todo: Sybase: copied over MSSQL; verify correctness
  227. // note: test database should have case-insensitive collation
  228. begin
  229. FieldtypeDefinitions[ftBoolean] := 'BIT';
  230. FieldtypeDefinitions[ftFloat] := 'FLOAT';
  231. FieldtypeDefinitions[ftCurrency]:= 'MONEY';
  232. FieldtypeDefinitions[ftDateTime]:= 'DATETIME';
  233. FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
  234. FieldtypeDefinitions[ftVarBytes]:= 'VARBINARY(10)';
  235. FieldtypeDefinitions[ftBlob] := 'IMAGE';
  236. FieldtypeDefinitions[ftMemo] := 'TEXT';
  237. FieldtypeDefinitions[ftGraphic] := '';
  238. FieldtypeDefinitions[ftGuid] := 'UNIQUEIDENTIFIER';
  239. FieldtypeDefinitions[ftWideString] := 'NVARCHAR(10)';
  240. FieldtypeDefinitions[ftFixedWideChar] := 'NCHAR(10)';
  241. //FieldtypeDefinitions[ftWideMemo] := 'NTEXT'; // Sybase has UNITEXT?
  242. // Proper blob support:
  243. FConnection.ExecuteDirect('SET TEXTSIZE 2147483647');
  244. if SQLServerType=ssMSSQL then
  245. begin
  246. // When running CREATE TABLE statements, allow NULLs by default - without
  247. // having to specify NULL all the time:
  248. // http://msdn.microsoft.com/en-us/library/ms174979.aspx
  249. //
  250. // Padding character fields is expected by ANSI and sqldb, as well as
  251. // recommended by Microsoft:
  252. // http://msdn.microsoft.com/en-us/library/ms187403.aspx
  253. FConnection.ExecuteDirect('SET ANSI_NULL_DFLT_ON ON; SET ANSI_PADDING ON; SET ANSI_WARNINGS OFF');
  254. end;
  255. if SQLServerType=ssSybase then
  256. begin
  257. // Evaluate NULL expressions according to ANSI SQL:
  258. // http://infocenter.sybase.com/archive/index.jsp?topic=/com.sybase.help.ase_15.0.commands/html/commands/commands85.htm
  259. FConnection.ExecuteDirect('SET ANSINULL ON');
  260. { Tests require these database options set
  261. 1) with ddl in tran; e.g.
  262. use master
  263. go
  264. sp_dboption pubs3, 'ddl in tran', true
  265. go
  266. Avoid errors like
  267. The 'CREATE TABLE' command is not allowed within a multi-statement transaction in the 'test' database.
  268. 2) allow nulls by default, e.g.
  269. use master
  270. go
  271. sp_dboption pubs3, 'allow nulls by default', true
  272. go
  273. }
  274. end;
  275. FTransaction.Commit;
  276. end;
  277. ssMySQL:
  278. begin
  279. FieldtypeDefinitions[ftWord] := 'SMALLINT UNSIGNED';
  280. // MySQL recognizes BOOLEAN, but as synonym for TINYINT, not true sql boolean datatype
  281. FieldtypeDefinitions[ftBoolean] := '';
  282. // Use 'DATETIME' for datetime fields instead of timestamp, because
  283. // mysql's timestamps are only valid in the range 1970-2038.
  284. // Downside is that fields defined as 'TIMESTAMP' aren't tested
  285. FieldtypeDefinitions[ftDateTime] := 'DATETIME';
  286. FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
  287. FieldtypeDefinitions[ftVarBytes] := 'VARBINARY(10)';
  288. FieldtypeDefinitions[ftMemo] := 'TEXT';
  289. FieldtypeDefinitions[ftLongWord] := 'INT UNSIGNED';
  290. // Add into my.ini: sql-mode="...,PAD_CHAR_TO_FULL_LENGTH,ANSI_QUOTES" or set it explicitly by:
  291. // PAD_CHAR_TO_FULL_LENGTH to avoid trimming trailing spaces contrary to SQL standard (MySQL 5.1.20+)
  292. FConnection.ExecuteDirect('SET SESSION sql_mode=''STRICT_ALL_TABLES,PAD_CHAR_TO_FULL_LENGTH,ANSI_QUOTES''');
  293. FTransaction.Commit;
  294. end;
  295. ssOracle:
  296. begin
  297. FieldtypeDefinitions[ftBoolean] := '';
  298. // At least Oracle 10, 11 do not support a BIGINT field:
  299. FieldtypeDefinitions[ftLargeInt] := 'NUMBER(19,0)';
  300. FieldtypeDefinitions[ftTime] := 'TIMESTAMP';
  301. FieldtypeDefinitions[ftMemo] := 'CLOB';
  302. FieldtypeDefinitions[ftWideString] := 'NVARCHAR2(10)';
  303. FieldtypeDefinitions[ftFixedWideChar] := 'NCHAR(10)';
  304. FieldtypeDefinitions[ftWideMemo] := 'NCLOB';
  305. end;
  306. ssPostgreSQL:
  307. begin
  308. FieldtypeDefinitions[ftCurrency] := 'MONEY'; // ODBC?!
  309. FieldtypeDefinitions[ftBlob] := 'BYTEA';
  310. FieldtypeDefinitions[ftMemo] := 'TEXT';
  311. FieldtypeDefinitions[ftGraphic] := '';
  312. FieldtypeDefinitions[ftGuid] := 'UUID';
  313. end;
  314. ssSQLite:
  315. begin
  316. // SQLite stores all values with decimal point as 8 byte (double) IEEE floating point numbers
  317. // (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)
  318. FieldtypeDefinitions[ftWord] := 'WORD';
  319. FieldtypeDefinitions[ftCurrency] := 'CURRENCY';
  320. FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
  321. FieldtypeDefinitions[ftVarBytes] := 'VARBINARY(10)';
  322. FieldtypeDefinitions[ftMemo] := 'CLOB'; //or TEXT SQLite supports both, but CLOB is sql standard (TEXT not)
  323. FieldtypeDefinitions[ftWideString] := 'NVARCHAR(10)';
  324. FieldtypeDefinitions[ftFixedWideChar] := 'NCHAR(10)';
  325. FieldtypeDefinitions[ftWideMemo] := 'NCLOB';
  326. end;
  327. end;
  328. if SQLConnType in [mysql40,mysql41] then
  329. begin
  330. // Mysql versions prior to 5.0.3 removes the trailing spaces on varchar
  331. // fields on insertion. So to test properly, we have to do the same
  332. for i := 0 to testValuesCount-1 do
  333. testStringValues[i] := TrimRight(testStringValues[i]);
  334. end;
  335. if SQLServerType in [ssMSSQL, ssSQLite, ssSybase] then
  336. // Some DB's do not support sql compliant boolean data type.
  337. for i := 0 to testValuesCount-1 do
  338. testValues[ftBoolean, i] := BoolToStr(testBooleanValues[i], '1', '0');
  339. if SQLServerType in [ssMySQL] then
  340. begin
  341. // Some DB's do not support milliseconds in datetime and time fields.
  342. for i := 0 to testValuesCount-1 do
  343. begin
  344. testTimeValues[i] := copy(testTimeValues[i],1,8)+'.000';
  345. testValues[ftTime,i] := copy(testTimeValues[i],1,8)+'.000';
  346. if length(testValues[ftDateTime,i]) > 19 then
  347. testValues[ftDateTime,i] := copy(testValues[ftDateTime,i],1,19)+'.000';
  348. end;
  349. end;
  350. if SQLServerType in [ssFirebird, ssInterbase, ssMSSQL, ssOracle, ssPostgreSQL, ssSybase] then
  351. begin
  352. // Some db's do not support times > 24:00:00
  353. testTimeValues[3]:='13:25:15.000';
  354. testValues[ftTime,3]:='13:25:15.000';
  355. if SQLServerType in [ssFirebird, ssInterbase, ssMSSQL, ssOracle] then
  356. begin
  357. // Firebird, Oracle, MS SQL Server do not support time = 24:00:00
  358. // MS SQL Server "datetime" supports only time up to 23:59:59.997
  359. testTimeValues[2]:='23:59:59.997';
  360. testValues[ftTime,2]:='23:59:59.997';
  361. end;
  362. end;
  363. if SQLServerType in [ssMSSQL, ssSybase] then
  364. // Some DB's do not support datetime values before 1753-01-01
  365. for i := 18 to testValuesCount-1 do
  366. testValues[ftDateTime,i] := testValues[ftDateTime,0];
  367. // DecimalSeparator must correspond to monetary locale (lc_monetary) set on PostgreSQL server
  368. // Here we assume, that locale on client side is same as locale on server
  369. if SQLServerType in [ssPostgreSQL] then
  370. for i := 0 to testValuesCount-1 do
  371. testValues[ftCurrency,i] := QuotedStr(CurrToStr(testCurrencyValues[i]));
  372. // SQLite does not support fixed length CHAR datatype
  373. if SQLServerType in [ssSQLite] then
  374. for i := 0 to testValuesCount-1 do
  375. testValues[ftFixedChar,i] := PadRight(testValues[ftFixedChar,i], 10);
  376. end;
  377. Function TSQLDBConnector.CreateQuery: TSQLQuery;
  378. begin
  379. Result := TSQLQuery.create(nil);
  380. with Result do
  381. begin
  382. database := Fconnection;
  383. transaction := Ftransaction;
  384. PacketRecords := -1; // To avoid: "Connection is busy with results for another hstmt" (ODBC,MSSQL)
  385. end;
  386. end;
  387. procedure TSQLDBConnector.SetTestUniDirectional(const AValue: boolean);
  388. begin
  389. FUniDirectional:=avalue;
  390. FQuery.UniDirectional:=AValue;
  391. end;
  392. function TSQLDBConnector.GetTestUniDirectional: boolean;
  393. begin
  394. result := FUniDirectional;
  395. end;
  396. procedure TSQLDBConnector.CreateNDatasets;
  397. var CountID : Integer;
  398. begin
  399. try
  400. Ftransaction.StartTransaction;
  401. TryDropIfExist('FPDEV');
  402. Fconnection.ExecuteDirect('create table FPDEV (' +
  403. ' ID INT NOT NULL, ' +
  404. ' NAME VARCHAR(50), ' +
  405. ' PRIMARY KEY (ID) ' +
  406. ')');
  407. FTransaction.CommitRetaining;
  408. for countID := 1 to MaxDataSet do
  409. Fconnection.ExecuteDirect('insert into FPDEV (ID,NAME) ' +
  410. 'values ('+inttostr(countID)+',''TestName'+inttostr(countID)+''')');
  411. Ftransaction.Commit;
  412. except
  413. on E: Exception do begin
  414. if dblogfilename<>'' then
  415. DoLogEvent(nil,detCustom,'Exception running CreateNDatasets: '+E.Message);
  416. if Ftransaction.Active then
  417. Ftransaction.Rollback
  418. end;
  419. end;
  420. end;
  421. procedure TSQLDBConnector.CreateFieldDataset;
  422. var
  423. CountID : Integer;
  424. FType : TFieldType;
  425. Sql,sql1: String;
  426. function String2Hex(Source: string): string;
  427. // Converts ASCII codes into hex
  428. var
  429. i: integer;
  430. begin
  431. result := '';
  432. for i := 1 to length(Source) do
  433. result := result + inttohex(ord(Source[i]),2);
  434. end;
  435. begin
  436. try
  437. Ftransaction.StartTransaction;
  438. TryDropIfExist('FPDEV_FIELD');
  439. Sql := 'create table FPDEV_FIELD (ID INT NOT NULL,';
  440. for FType := low(TFieldType)to high(TFieldType) do
  441. if FieldtypeDefinitions[FType]<>'' then
  442. sql := sql + 'F' + Fieldtypenames[FType] + ' ' +
  443. FieldtypeDefinitions[FType] + ',';
  444. Sql := Sql + 'PRIMARY KEY (ID))';
  445. FConnection.ExecuteDirect(Sql);
  446. FTransaction.CommitRetaining;
  447. for countID := 0 to testValuesCount-1 do
  448. begin
  449. Sql := 'insert into FPDEV_FIELD (ID';
  450. Sql1 := 'values ('+IntToStr(countID);
  451. for FType := low(TFieldType)to high(TFieldType) do
  452. if FieldtypeDefinitions[FType]<>'' then
  453. begin
  454. sql := sql + ',F' + Fieldtypenames[FType];
  455. if testValues[FType,CountID] <> '' then
  456. if FType in [ftBoolean, ftCurrency] then
  457. sql1 := sql1 + ',' + testValues[FType,CountID]
  458. else if (FType in [ftBlob, ftBytes, ftGraphic, ftVarBytes]) and
  459. (SQLServerType = ssOracle) then
  460. // Oracle does not accept string literals in blob insert statements
  461. // convert 'DEADBEEF' hex literal to binary:
  462. sql1 := sql1 + ', HEXTORAW(' + QuotedStr(String2Hex(testValues[FType,CountID])) + ') '
  463. else if (FType = ftDate) and
  464. (SQLServerType = ssOracle) then
  465. // Oracle requires date conversion; otherwise
  466. // ORA-01861: literal does not match format string
  467. // ANSI/ISO date literal:
  468. sql1 := sql1 + ', DATE ' + QuotedStr(testValues[FType,CountID])
  469. else if (FType = ftDateTime) and
  470. (SQLServerType = ssOracle) then begin
  471. // similar to ftDate handling
  472. // Could be a real date+time or only date. Does not consider only time.
  473. if pos(' ',testValues[FType,CountID])>0 then
  474. sql1 := sql1 + ', TIMESTAMP ' + QuotedStr(testValues[FType,CountID])
  475. else
  476. sql1 := sql1 + ', DATE ' + QuotedStr(testValues[FType,CountID]);
  477. end
  478. else if (FType = ftTime) and
  479. (SQLServerType = ssOracle) then
  480. // similar to ftDate handling
  481. // More or less arbitrary default time; there is no time-only data type in Oracle.
  482. sql1 := sql1 + ', TIMESTAMP ' + QuotedStr('0001-01-01 '+testValues[FType,CountID])
  483. else
  484. sql1 := sql1 + ',' + QuotedStr(testValues[FType,CountID])
  485. else
  486. sql1 := sql1 + ',NULL';
  487. end;
  488. Sql := sql + ')';
  489. Sql1 := sql1+ ')';
  490. Fconnection.ExecuteDirect(sql + ' ' + sql1);
  491. end;
  492. Ftransaction.Commit;
  493. except
  494. on E: Exception do begin
  495. if dblogfilename<>'' then
  496. DoLogEvent(nil,detCustom,'Exception running CreateFieldDataset: '+E.Message);
  497. if Ftransaction.Active then Ftransaction.Rollback;
  498. end;
  499. end;
  500. end;
  501. procedure TSQLDBConnector.DoLogEvent(Sender: TSQLConnection;
  502. EventType: TDBEventType; Const Msg: String);
  503. var
  504. Category: string;
  505. begin
  506. case EventType of
  507. detCustom: Category:='Custom';
  508. detPrepare: Category:='Prepare';
  509. detExecute: Category:='Execute';
  510. detFetch: Category:='Fetch';
  511. detCommit: Category:='Commit';
  512. detRollBack: Category:='Rollback';
  513. else Category:='Unknown event. Please fix program code.';
  514. end;
  515. LogMessage(Category,Msg);
  516. end;
  517. procedure TSQLDBConnector.DropNDatasets;
  518. begin
  519. if assigned(FTransaction) then
  520. begin
  521. try
  522. if Ftransaction.Active then Ftransaction.Rollback;
  523. Ftransaction.StartTransaction;
  524. Fconnection.ExecuteDirect('DROP TABLE FPDEV');
  525. Ftransaction.Commit;
  526. Except
  527. on E: Exception do begin
  528. if dblogfilename<>'' then
  529. DoLogEvent(nil,detCustom,'Exception running DropNDatasets: '+E.Message);
  530. if Ftransaction.Active then Ftransaction.Rollback
  531. end;
  532. end;
  533. end;
  534. end;
  535. procedure TSQLDBConnector.DropFieldDataset;
  536. begin
  537. if assigned(FTransaction) then
  538. begin
  539. try
  540. if Ftransaction.Active then Ftransaction.Rollback;
  541. Ftransaction.StartTransaction;
  542. Fconnection.ExecuteDirect('DROP TABLE FPDEV_FIELD');
  543. Ftransaction.Commit;
  544. Except
  545. on E: Exception do begin
  546. if dblogfilename<>'' then
  547. DoLogEvent(nil,detCustom,'Exception running DropFieldDataset: '+E.Message);
  548. if Ftransaction.Active then Ftransaction.Rollback
  549. end;
  550. end;
  551. end;
  552. end;
  553. Function TSQLDBConnector.InternalGetNDataset(n: integer): TDataset;
  554. begin
  555. Result := CreateQuery;
  556. with (Result as TSQLQuery) do
  557. begin
  558. sql.clear;
  559. sql.add('SELECT * FROM FPDEV WHERE ID < '+inttostr(n+1)+' ORDER BY ID');
  560. UniDirectional:=TestUniDirectional;
  561. end;
  562. end;
  563. Function TSQLDBConnector.InternalGetFieldDataset: TDataSet;
  564. begin
  565. Result := CreateQuery;
  566. with (Result as TSQLQuery) do
  567. begin
  568. sql.clear;
  569. sql.add('SELECT * FROM FPDEV_FIELD');
  570. UniDirectional:=TestUniDirectional;
  571. end;
  572. end;
  573. procedure TSQLDBConnector.TryDropIfExist(ATableName: String);
  574. begin
  575. // This makes life so much easier, since it avoids the exception if the table already
  576. // exists. And while this exception is in a try..except statement, the debugger
  577. // always shows the exception, which is pretty annoying.
  578. try
  579. case SQLServerType of
  580. ssFirebird:
  581. begin
  582. // This only works with Firebird 2+
  583. FConnection.ExecuteDirect('execute block as begin if (exists (select 1 from rdb$relations where upper(rdb$relation_name)=''' + UpperCase(ATableName) + ''')) '+
  584. 'then execute statement ''drop table ' + ATableName + ';'';end');
  585. FTransaction.CommitRetaining;
  586. end;
  587. ssMSSQL:
  588. begin
  589. // Checking is needed here to avoid getting "auto rollback" of a subsequent CREATE TABLE statement
  590. // which leads to the rollback not referring to the right transaction=>SQL error
  591. // Use SQL92 ISO standard INFORMATION_SCHEMA:
  592. FConnection.ExecuteDirect(
  593. 'if exists (select * from INFORMATION_SCHEMA.TABLES where TABLE_TYPE=''BASE TABLE'' AND TABLE_NAME=''' + ATableName + ''')'+
  594. ' drop table ' + ATableName );
  595. end;
  596. ssMySQL:
  597. begin
  598. FConnection.ExecuteDirect('drop table if exists ' + ATableName);
  599. end;
  600. ssPostgreSQL,
  601. ssSQLite:
  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.TryDropSequence(ASequenceName: String);
  635. var
  636. NoSeq : Boolean;
  637. begin
  638. NoSeq:=False;
  639. try
  640. case SQLServerType of
  641. ssInterbase,
  642. ssFirebird: FConnection.ExecuteDirect('DROP GENERATOR '+ASequenceName);
  643. ssOracle,
  644. ssPostgreSQL,
  645. ssSybase,
  646. ssMSSQL : FConnection.ExecuteDirect('DROP SEQUENCE '+ASequenceName+' START WITH 1 INCREMENT BY 1');
  647. ssSQLite : FConnection.ExecuteDirect('delete from sqlite_sequence where (name='''+ASequenceName+''')');
  648. else
  649. NoSeq:=True;
  650. end;
  651. except
  652. FTransaction.RollbackRetaining;
  653. end;
  654. if NoSeq then
  655. Raise EDatabaseError.Create('Engine does not support sequences');
  656. end;
  657. procedure TSQLDBConnector.TryCreateSequence(ASequenceName: String);
  658. var
  659. NoSeq : Boolean;
  660. begin
  661. NoSeq:=False;
  662. case SQLServerType of
  663. ssInterbase,
  664. ssFirebird: FConnection.ExecuteDirect('CREATE GENERATOR '+ASequenceName);
  665. ssOracle,
  666. ssPostgreSQL,
  667. ssSybase,
  668. ssMSSQL : FConnection.ExecuteDirect('CREATE SEQUENCE '+ASequenceName+' START WITH 1 INCREMENT BY 1');
  669. ssSQLite : FConnection.ExecuteDirect('insert into sqlite_sequence (name,seq) values ('''+ASequenceName+''',1)');
  670. else
  671. Raise EDatabaseError.Create('Engine does not support sequences');
  672. end;
  673. end;
  674. procedure TSQLDBConnector.ExecuteDirect(const SQL: string);
  675. begin
  676. Connection.ExecuteDirect(SQL);
  677. end;
  678. procedure TSQLDBConnector.CommitDDL;
  679. begin
  680. // Commits schema definition and manipulation statements;
  681. // Firebird/Interbase need a commit after a DDL statement. Not necessary for the other connections
  682. if SQLServerType in [ssFirebird, ssInterbase] then
  683. Transaction.CommitRetaining;
  684. end;
  685. Procedure TSQLDBConnector.FreeTransaction;
  686. begin
  687. FreeAndNil(FTransaction);
  688. end;
  689. destructor TSQLDBConnector.Destroy;
  690. begin
  691. FreeAndNil(FQuery);
  692. if assigned(FTransaction) then
  693. begin
  694. try
  695. if not (stoUseImplicit in Transaction.Options) then
  696. begin
  697. if Ftransaction.Active then
  698. Ftransaction.Rollback;
  699. Ftransaction.StartTransaction;
  700. end;
  701. TryDropIfExist('FPDEV2');
  702. if not (stoUseImplicit in Transaction.Options) then
  703. Ftransaction.Commit;
  704. Except
  705. if Ftransaction.Active and not (stoUseImplicit in Transaction.Options) then
  706. Ftransaction.Rollback;
  707. end; // try
  708. end;
  709. FreeTransaction;
  710. FreeAndNil(FConnection);
  711. inherited Destroy;
  712. end;
  713. constructor TSQLDBConnector.Create;
  714. begin
  715. FConnection := nil;
  716. CreateFConnection;
  717. FQuery := CreateQuery;
  718. Inherited;
  719. end;
  720. initialization
  721. RegisterClass(TSQLDBConnector);
  722. end.