sqldbtoolsunit.pas 17 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537
  1. unit SQLDBToolsUnit;
  2. {$mode objfpc}{$H+}
  3. interface
  4. uses
  5. Classes, SysUtils, toolsunit
  6. ,db, sqldb
  7. ,mysql40conn, mysql41conn, mysql50conn, mysql51conn, mysql55conn,ibconnection
  8. {$IFNDEF WIN64}
  9. {See packages\fcl-db\src\sqldb\postgres\fpmake.pp: postgres connector won't be present on Win64}
  10. ,pqconnection
  11. {$ENDIF WIN64}
  12. ,odbcconn
  13. {$IFNDEF WIN64}
  14. {See packages\fcl-db\fpmake.pp: Oracle connector is not built if PostgreSQL connectoris not built}
  15. ,oracleconnection
  16. {$ENDIF WIN64}
  17. ,sqlite3conn
  18. {$IFNDEF WIN64}
  19. {This won't be available on Windows 64, either; perhaps other systems as well}
  20. ,mssqlconn
  21. {$ENDIF WIN64}
  22. ;
  23. type
  24. TSQLDBType = (mysql40,mysql41,mysql50,mysql51,mysql55,postgresql,interbase,odbc,oracle,sqlite3,mssql,sybase);
  25. TSQLServerType = (ssFirebird, ssInterbase, ssMSSQL, ssMySQL, ssOracle, ssPostgreSQL, ssSQLite, ssSybase, ssUnknown);
  26. const MySQLdbTypes = [mysql40,mysql41,mysql50,mysql51,mysql55];
  27. DBTypesNames : Array [TSQLDBType] of String[19] =
  28. ('MYSQL40','MYSQL41','MYSQL50','MYSQL51','MYSQL55','POSTGRESQL','INTERBASE','ODBC','ORACLE','SQLITE3','MSSQL','SYBASE');
  29. FieldtypeDefinitionsConst : Array [TFieldType] of String[20] =
  30. (
  31. '',
  32. 'VARCHAR(10)',
  33. 'SMALLINT',
  34. 'INTEGER',
  35. '',
  36. 'BOOLEAN',
  37. 'FLOAT',
  38. '', // ftCurrency
  39. 'DECIMAL(18,4)',// ftBCD
  40. 'DATE',
  41. 'TIME',
  42. 'TIMESTAMP', // ftDateTime
  43. '',
  44. '',
  45. '',
  46. 'BLOB', // ftBlob
  47. 'BLOB', // ftMemo
  48. 'BLOB', // ftGraphic
  49. '',
  50. '',
  51. '',
  52. '',
  53. '',
  54. 'CHAR(10)', // ftFixedChar
  55. '',
  56. 'BIGINT', // ftLargeInt
  57. '',
  58. '',
  59. '',
  60. '',
  61. '',
  62. '',
  63. '',
  64. '',
  65. '',
  66. '', // ftGuid
  67. 'TIMESTAMP', // ftTimestamp
  68. 'NUMERIC(18,6)',// ftFmtBCD
  69. '',
  70. ''
  71. );
  72. type
  73. { TSQLDBConnector }
  74. TSQLDBConnector = class(TDBConnector)
  75. private
  76. FConnection : TSQLConnection;
  77. FTransaction : TSQLTransaction;
  78. FQuery : TSQLQuery;
  79. FUniDirectional: boolean;
  80. procedure CreateFConnection;
  81. procedure CreateFTransaction;
  82. Function CreateQuery : TSQLQuery;
  83. protected
  84. procedure SetTestUniDirectional(const AValue: boolean); override;
  85. function GetTestUniDirectional: boolean; override;
  86. procedure CreateNDatasets; override;
  87. procedure CreateFieldDataset; override;
  88. procedure DropNDatasets; override;
  89. procedure DropFieldDataset; override;
  90. Function InternalGetNDataset(n : integer) : TDataset; override;
  91. Function InternalGetFieldDataset : TDataSet; override;
  92. procedure TryDropIfExist(ATableName : String);
  93. public
  94. destructor Destroy; override;
  95. constructor Create; override;
  96. property Connection : TSQLConnection read FConnection;
  97. property Transaction : TSQLTransaction read FTransaction;
  98. property Query : TSQLQuery read FQuery;
  99. end;
  100. var SQLDbType : TSQLDBType;
  101. SQLServerType : TSQLServerType;
  102. FieldtypeDefinitions : Array [TFieldType] of String[20];
  103. implementation
  104. uses StrUtils;
  105. type
  106. TSQLServerTypesMapItem = record
  107. s: string;
  108. t: TSQLServerType;
  109. end;
  110. const
  111. // names as returned by ODBC SQLGetInfo(..., SQL_DBMS_NAME, ...) and GetConnectionInfo(citServerType)
  112. SQLServerTypesMap : array [0..7] of TSQLServerTypesMapItem = (
  113. (s: 'Firebird'; t: ssFirebird),
  114. (s: 'Interbase'; t: ssInterbase),
  115. (s: 'Microsoft SQL Server'; t: ssMSSQL),
  116. (s: 'MySQL'; t: ssMySQL),
  117. (s: 'Oracle'; t: ssOracle),
  118. (s: 'PostgreSQL'; t: ssPostgreSQL),
  119. (s: 'SQLite3'; t: ssSQLite),
  120. (s: 'ASE'; t: ssSybase)
  121. );
  122. // fall back mapping
  123. SQLDBTypeToServerTypeMap : array[TSQLDbType] of TSQLServerType =
  124. (ssMySQL,ssMySQL,ssMySQL,ssMySQL,ssMySQL,ssPostgreSQL,ssInterbase,ssUnknown,ssOracle,ssSQLite,ssMSSQL,ssSybase);
  125. { TSQLDBConnector }
  126. procedure TSQLDBConnector.CreateFConnection;
  127. var t : TSQLDBType;
  128. i : integer;
  129. s : string;
  130. begin
  131. for t := low(DBTypesNames) to high(DBTypesNames) do
  132. if UpperCase(dbconnectorparams) = DBTypesNames[t] then SQLDbType := t;
  133. if SQLDbType = MYSQL40 then Fconnection := TMySQL40Connection.Create(nil);
  134. if SQLDbType = MYSQL41 then Fconnection := TMySQL41Connection.Create(nil);
  135. if SQLDbType = MYSQL50 then Fconnection := TMySQL50Connection.Create(nil);
  136. if SQLDbType = MYSQL51 then Fconnection := TMySQL51Connection.Create(nil);
  137. if SQLDbType = MYSQL55 then Fconnection := TMySQL55Connection.Create(nil);
  138. if SQLDbType = SQLITE3 then Fconnection := TSQLite3Connection.Create(nil);
  139. if SQLDbType = POSTGRESQL then Fconnection := TPQConnection.Create(nil);
  140. if SQLDbType = INTERBASE then Fconnection := TIBConnection.Create(nil);
  141. if SQLDbType = ODBC then Fconnection := TODBCConnection.Create(nil);
  142. {$IFNDEF Win64}
  143. if SQLDbType = ORACLE then Fconnection := TOracleConnection.Create(nil);
  144. {$ENDIF Win64}
  145. if SQLDbType = MSSQL then Fconnection := TMSSQLConnection.Create(nil);
  146. if SQLDbType = SYBASE then Fconnection := TSybaseConnection.Create(nil);
  147. 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''');
  148. with Fconnection do
  149. begin
  150. DatabaseName := dbname;
  151. UserName := dbuser;
  152. Password := dbpassword;
  153. HostName := dbhostname;
  154. if (dbhostname='') and (SQLDbType=interbase) then
  155. begin
  156. // Firebird embedded: create database file if it doesn't yet exist
  157. // Note: pagesize parameter has influence on behavior. We're using
  158. // Firebird default here.
  159. if not(fileexists(dbname)) then
  160. CreateDB; //Create testdb
  161. end;
  162. if length(dbQuoteChars)>1 then
  163. begin
  164. FieldNameQuoteChars:=dbquotechars;
  165. end;
  166. Open;
  167. end;
  168. // determine remote SQL Server to which we are connected
  169. s := Fconnection.GetConnectionInfo(citServerType);
  170. if s = '' then
  171. SQLServerType := SQLDbTypeToServerTypeMap[SQLDbType] // if citServerType isn't implemented
  172. else
  173. for i := low(SQLServerTypesMap) to high(SQLServerTypesMap) do
  174. if SQLServerTypesMap[i].s = s then
  175. SQLServerType := SQLServerTypesMap[i].t;
  176. FieldtypeDefinitions := FieldtypeDefinitionsConst;
  177. case SQLServerType of
  178. ssFirebird, ssInterbase:
  179. begin
  180. FieldtypeDefinitions[ftBoolean] := '';
  181. FieldtypeDefinitions[ftMemo] := 'BLOB SUB_TYPE TEXT';
  182. end;
  183. ssMSSQL, ssSybase:
  184. // todo: Sybase: copied over MSSQL; verify correctness
  185. begin
  186. FieldtypeDefinitions[ftBoolean] := 'BIT';
  187. FieldtypeDefinitions[ftCurrency]:= 'MONEY';
  188. FieldtypeDefinitions[ftDate] := 'DATETIME';
  189. FieldtypeDefinitions[ftTime] := '';
  190. FieldtypeDefinitions[ftDateTime]:= 'DATETIME';
  191. FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
  192. FieldtypeDefinitions[ftVarBytes]:= 'VARBINARY(10)';
  193. FieldtypeDefinitions[ftBlob] := 'IMAGE';
  194. FieldtypeDefinitions[ftMemo] := 'TEXT';
  195. FieldtypeDefinitions[ftGraphic] := '';
  196. end;
  197. ssMySQL:
  198. begin
  199. //MySQL recognizes BOOLEAN, but as synonym for TINYINT, not true sql boolean datatype
  200. FieldtypeDefinitions[ftBoolean] := '';
  201. FieldtypeDefinitions[ftFloat] := 'DOUBLE';
  202. // Use 'DATETIME' for datetime-fields instead of timestamp, because
  203. // mysql's timestamps are only valid in the range 1970-2038.
  204. // Downside is that fields defined as 'TIMESTAMP' aren't tested
  205. FieldtypeDefinitions[ftDateTime] := 'DATETIME';
  206. FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
  207. FieldtypeDefinitions[ftVarBytes] := 'VARBINARY(10)';
  208. FieldtypeDefinitions[ftMemo] := 'TEXT';
  209. end;
  210. ssOracle:
  211. begin
  212. FieldtypeDefinitions[ftBoolean] := '';
  213. FieldtypeDefinitions[ftTime] := 'TIMESTAMP';
  214. FieldtypeDefinitions[ftMemo] := 'CLOB';
  215. end;
  216. ssPostgreSQL:
  217. begin
  218. FieldtypeDefinitions[ftCurrency] := 'MONEY';
  219. FieldtypeDefinitions[ftBlob] := 'BYTEA';
  220. FieldtypeDefinitions[ftMemo] := 'TEXT';
  221. FieldtypeDefinitions[ftGraphic] := '';
  222. end;
  223. ssSQLite:
  224. begin
  225. FieldtypeDefinitions[ftCurrency] := 'CURRENCY';
  226. FieldtypeDefinitions[ftBytes] := 'BINARY(5)';
  227. FieldtypeDefinitions[ftVarBytes] := 'VARBINARY(10)';
  228. FieldtypeDefinitions[ftMemo] := 'CLOB'; //or TEXT SQLite supports both, but CLOB is sql standard (TEXT not)
  229. end;
  230. end;
  231. if SQLDbType in [mysql40,mysql41] then
  232. begin
  233. // Mysql versions prior to 5.0.3 removes the trailing spaces on varchar
  234. // fields on insertion. So to test properly, we have to do the same
  235. for i := 0 to testValuesCount-1 do
  236. testStringValues[i] := TrimRight(testStringValues[i]);
  237. end;
  238. if SQLServerType in [ssMySQL] then
  239. begin
  240. // Some DB's do not support milliseconds in datetime and time fields.
  241. for i := 0 to testValuesCount-1 do
  242. begin
  243. testTimeValues[i] := copy(testTimeValues[i],1,8)+'.000';
  244. testValues[ftTime,i] := copy(testTimeValues[i],1,8)+'.000';
  245. if length(testValues[ftDateTime,i]) > 19 then
  246. testValues[ftDateTime,i] := copy(testValues[ftDateTime,i],1,19)+'.000';
  247. end;
  248. end;
  249. if SQLServerType in [ssFirebird, ssInterbase, ssMSSQL, ssPostgreSQL, ssSybase] then
  250. begin
  251. // Some db's do not support times > 24:00:00
  252. testTimeValues[3]:='13:25:15.000';
  253. testValues[ftTime,3]:='13:25:15.000';
  254. if SQLServerType in [ssFirebird, ssInterbase] then
  255. begin
  256. // Firebird does not support time = 24:00:00
  257. testTimeValues[2]:='23:00:00.000';
  258. testValues[ftTime,2]:='23:00:00.000';
  259. end;
  260. end;
  261. // DecimalSeparator must correspond to monetary locale (lc_monetary) set on PostgreSQL server
  262. // Here we assume, that locale on client side is same as locale on server
  263. if SQLServerType in [ssPostgreSQL] then
  264. for i := 0 to testValuesCount-1 do
  265. testValues[ftCurrency,i] := QuotedStr(CurrToStr(testCurrencyValues[i]));
  266. // SQLite does not support fixed length CHAR datatype
  267. // MySQL by default trimms trailing spaces on retrieval; so set sql-mode="PAD_CHAR_TO_FULL_LENGTH" - supported from MySQL 5.1.20
  268. // MSSQL set SET ANSI_PADDING ON
  269. // todo: verify Sybase behaviour
  270. if SQLServerType in [ssSQLite] then
  271. for i := 0 to testValuesCount-1 do
  272. testValues[ftFixedChar,i] := PadRight(testValues[ftFixedChar,i], 10);
  273. end;
  274. procedure TSQLDBConnector.CreateFTransaction;
  275. begin
  276. Ftransaction := tsqltransaction.create(nil);
  277. with Ftransaction do
  278. database := Fconnection;
  279. end;
  280. Function TSQLDBConnector.CreateQuery : TSQLQuery;
  281. begin
  282. Result := TSQLQuery.create(nil);
  283. with Result do
  284. begin
  285. database := Fconnection;
  286. transaction := Ftransaction;
  287. PacketRecords := -1; // To avoid: "Connection is busy with results for another hstmt" (ODBC,MSSQL)
  288. end;
  289. end;
  290. procedure TSQLDBConnector.SetTestUniDirectional(const AValue: boolean);
  291. begin
  292. FUniDirectional:=avalue;
  293. FQuery.UniDirectional:=AValue;
  294. end;
  295. function TSQLDBConnector.GetTestUniDirectional: boolean;
  296. begin
  297. result := FUniDirectional;
  298. end;
  299. procedure TSQLDBConnector.CreateNDatasets;
  300. var CountID : Integer;
  301. begin
  302. try
  303. Ftransaction.StartTransaction;
  304. TryDropIfExist('FPDEV');
  305. Fconnection.ExecuteDirect('create table FPDEV (' +
  306. ' ID INT NOT NULL, ' +
  307. ' NAME VARCHAR(50), ' +
  308. ' PRIMARY KEY (ID) ' +
  309. ')');
  310. FTransaction.CommitRetaining;
  311. for countID := 1 to MaxDataSet do
  312. Fconnection.ExecuteDirect('insert into FPDEV (ID,NAME)' +
  313. 'values ('+inttostr(countID)+',''TestName'+inttostr(countID)+''')');
  314. Ftransaction.Commit;
  315. except
  316. if Ftransaction.Active then Ftransaction.Rollback
  317. end;
  318. end;
  319. procedure TSQLDBConnector.CreateFieldDataset;
  320. var CountID : Integer;
  321. FType : TFieldType;
  322. Sql,sql1: String;
  323. begin
  324. try
  325. Ftransaction.StartTransaction;
  326. TryDropIfExist('FPDEV_FIELD');
  327. Sql := 'create table FPDEV_FIELD (ID INT NOT NULL,';
  328. for FType := low(TFieldType)to high(TFieldType) do
  329. if FieldtypeDefinitions[FType]<>'' then
  330. sql := sql + 'F' + Fieldtypenames[FType] + ' ' +FieldtypeDefinitions[FType]+ ',';
  331. Sql := Sql + 'PRIMARY KEY (ID))';
  332. FConnection.ExecuteDirect(Sql);
  333. FTransaction.CommitRetaining;
  334. for countID := 0 to testValuesCount-1 do
  335. begin
  336. Sql := 'insert into FPDEV_FIELD (ID';
  337. Sql1 := 'values ('+IntToStr(countID);
  338. for FType := low(TFieldType)to high(TFieldType) do
  339. if FieldtypeDefinitions[FType]<>'' then
  340. begin
  341. sql := sql + ',F' + Fieldtypenames[FType];
  342. if testValues[FType,CountID] <> '' then
  343. if FType in [ftCurrency] then
  344. sql1 := sql1 + ',' + testValues[FType,CountID]
  345. else
  346. sql1 := sql1 + ',' + QuotedStr(testValues[FType,CountID])
  347. else
  348. sql1 := sql1 + ',NULL';
  349. end;
  350. Sql := sql + ')';
  351. Sql1 := sql1+ ')';
  352. Fconnection.ExecuteDirect(sql + ' ' + sql1);
  353. end;
  354. Ftransaction.Commit;
  355. except
  356. on E: Exception do begin
  357. //writeln(E.Message);
  358. if Ftransaction.Active then Ftransaction.Rollback;
  359. end;
  360. end;
  361. end;
  362. procedure TSQLDBConnector.DropNDatasets;
  363. begin
  364. if assigned(FTransaction) then
  365. begin
  366. try
  367. if Ftransaction.Active then Ftransaction.Rollback;
  368. Ftransaction.StartTransaction;
  369. Fconnection.ExecuteDirect('DROP TABLE FPDEV');
  370. Ftransaction.Commit;
  371. Except
  372. if Ftransaction.Active then Ftransaction.Rollback
  373. end;
  374. end;
  375. end;
  376. procedure TSQLDBConnector.DropFieldDataset;
  377. begin
  378. if assigned(FTransaction) then
  379. begin
  380. try
  381. if Ftransaction.Active then Ftransaction.Rollback;
  382. Ftransaction.StartTransaction;
  383. Fconnection.ExecuteDirect('DROP TABLE FPDEV_FIELD');
  384. Ftransaction.Commit;
  385. Except
  386. if Ftransaction.Active then Ftransaction.Rollback
  387. end;
  388. end;
  389. end;
  390. function TSQLDBConnector.InternalGetNDataset(n: integer): TDataset;
  391. begin
  392. Result := CreateQuery;
  393. with (Result as TSQLQuery) do
  394. begin
  395. sql.clear;
  396. sql.add('SELECT * FROM FPDEV WHERE ID < '+inttostr(n+1));
  397. UniDirectional:=TestUniDirectional;
  398. end;
  399. end;
  400. function TSQLDBConnector.InternalGetFieldDataset: TDataSet;
  401. begin
  402. Result := CreateQuery;
  403. with (Result as TSQLQuery) do
  404. begin
  405. sql.clear;
  406. sql.add('SELECT * FROM FPDEV_FIELD');
  407. tsqlquery(Result).UniDirectional:=TestUniDirectional;
  408. end;
  409. end;
  410. procedure TSQLDBConnector.TryDropIfExist(ATableName: String);
  411. begin
  412. // This makes life soo much easier, since it avoids the exception if the table already
  413. // exists. And while this exeption is in a try..except statement, the debugger
  414. // always shows the exception, which is pretty annoying.
  415. try
  416. if SQLDbType = INTERBASE then
  417. begin
  418. // This only works with Firebird 2+
  419. FConnection.ExecuteDirect('execute block as begin if (exists (select 1 from rdb$relations where rdb$relation_name=''' + ATableName + ''')) '+
  420. 'then execute statement ''drop table ' + ATAbleName + ';'';end');
  421. FTransaction.CommitRetaining;
  422. end;
  423. if SQLDBType = mssql then
  424. begin
  425. // Checking is needed here to avoid getting "auto rollback" of a subsequent CREATE TABLE statement
  426. // which leads to the rollback not referring to the right transaction=>SQL error
  427. // Use SQL92 ISO standard INFORMATION_SCHEMA:
  428. FConnection.ExecuteDirect(
  429. 'if exists (select * from INFORMATION_SCHEMA.TABLES where TABLE_TYPE=''BASE TABLE'' AND TABLE_NAME=''' + ATableName + ''') '+
  430. 'begin '+
  431. 'drop table ' + ATAbleName + ' '+
  432. 'end');
  433. FTransaction.CommitRetaining;
  434. end;
  435. if SQLDbType = sybase then
  436. begin
  437. // Checking is needed here to avoid getting "auto rollback" of a subsequent CREATE TABLE statement
  438. // which leads to the rollback not referring to the right transaction=>SQL error
  439. // Can't use SQL standard information_schema; instead query sysobjects for User tables
  440. FConnection.ExecuteDirect(
  441. 'if exists (select * from sysobjects where type = ''U'' and name=''' + ATableName + ''') '+
  442. 'begin '+
  443. 'drop table ' + ATAbleName + ' '+
  444. 'end');
  445. end;
  446. except
  447. FTransaction.RollbackRetaining;
  448. end;
  449. end;
  450. destructor TSQLDBConnector.Destroy;
  451. begin
  452. if assigned(FTransaction) then
  453. begin
  454. try
  455. if Ftransaction.Active then Ftransaction.Rollback;
  456. Ftransaction.StartTransaction;
  457. Fconnection.ExecuteDirect('DROP TABLE FPDEV2');
  458. Ftransaction.Commit;
  459. Except
  460. if Ftransaction.Active then Ftransaction.Rollback
  461. end; // try
  462. end;
  463. inherited Destroy;
  464. FreeAndNil(FQuery);
  465. FreeAndNil(FTransaction);
  466. FreeAndNil(FConnection);
  467. end;
  468. constructor TSQLDBConnector.Create;
  469. begin
  470. FConnection := nil;
  471. CreateFConnection;
  472. CreateFTransaction;
  473. FQuery := CreateQuery;
  474. FConnection.Transaction := FTransaction;
  475. Inherited;
  476. end;
  477. initialization
  478. RegisterClass(TSQLDBConnector);
  479. end.