dbsetup.cpp 16 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419
  1. /*
  2. *openPilot Log - A FOSS Pilot Logbook Application
  3. *Copyright (C) 2020 Felix Turowsky
  4. *
  5. *This program is free software: you can redistribute it and/or modify
  6. *it under the terms of the GNU General Public License as published by
  7. *the Free Software Foundation, either version 3 of the License, or
  8. *(at your option) any later version.
  9. *
  10. *This program is distributed in the hope that it will be useful,
  11. *but WITHOUT ANY WARRANTY; without even the implied warranty of
  12. *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
  13. *GNU General Public License for more details.
  14. *
  15. *You should have received a copy of the GNU General Public License
  16. *along with this program. If not, see <https://www.gnu.org/licenses/>.
  17. */
  18. #include "dbsetup.h"
  19. #include "debug.h"
  20. // Statements for creation of database tables, Revision 10
  21. const QString createTablePilots = "CREATE TABLE \"pilots\" ( "
  22. "\"pilot_id\" INTEGER NOT NULL, "
  23. "\"piclastname\" TEXT NOT NULL, "
  24. "\"picfirstname\" TEXT, "
  25. "\"alias\" TEXT, "
  26. "\"company\" TEXT, "
  27. "\"employeeid\" TEXT, "
  28. "\"phone\" TEXT, "
  29. "\"email\" TEXT, "
  30. "\"displayname\" TEXT, "
  31. "PRIMARY KEY(\"pilot_id\" AUTOINCREMENT)"
  32. ")";
  33. const QString createTableTails = "CREATE TABLE \"tails\" ( "
  34. "\"tail_id\" INTEGER NOT NULL, "
  35. "\"registration\" TEXT NOT NULL, "
  36. "\"company\" TEXT, "
  37. "\"make\" TEXT, "
  38. "\"model\" TEXT, "
  39. "\"variant\" TEXT, "
  40. "\"singlepilot\" INTEGER, "
  41. "\"multipilot\" INTEGER, "
  42. "\"singleengine\" INTEGER, "
  43. "\"multiengine\" INTEGER, "
  44. "\"unpowered\" INTEGER, "
  45. "\"piston\" INTEGER, "
  46. "\"turboprop\" INTEGER, "
  47. "\"jet\" INTEGER, "
  48. "\"light\" INTEGER, "
  49. "\"medium\" INTEGER, "
  50. "\"heavy\" INTEGER, "
  51. "\"super\" INTEGER, "
  52. "PRIMARY KEY(\"tail_id\" AUTOINCREMENT)"
  53. ")";
  54. const QString createTableFlights = "CREATE TABLE \"flights\" ("
  55. "\"flight_id\" INTEGER NOT NULL, "
  56. "\"doft\" NUMERIC NOT NULL, "
  57. "\"dept\" TEXT NOT NULL, "
  58. "\"dest\" TEXT NOT NULL, "
  59. "\"tofb\" INTEGER NOT NULL, "
  60. "\"tonb\" INTEGER NOT NULL, "
  61. "\"pic\" INTEGER NOT NULL, "
  62. "\"acft\" INTEGER NOT NULL, "
  63. "\"tblk\" INTEGER NOT NULL, "
  64. "\"tSPSE\" INTEGER, "
  65. "\"tSPME\" INTEGER, "
  66. "\"tMP\" INTEGER, "
  67. "\"tNIGHT\" INTEGER, "
  68. "\"tIFR\" INTEGER, "
  69. "\"tPIC\" INTEGER, "
  70. "\"tPICUS\" INTEGER, "
  71. "\"tSIC\" INTEGER, "
  72. "\"tDUAL\" INTEGER, "
  73. "\"tFI\" INTEGER, "
  74. "\"tSIM\" INTEGER, "
  75. "\"pilotFlying\" INTEGER, "
  76. "\"toDay\" INTEGER, "
  77. "\"toNight\" INTEGER, "
  78. "\"ldgDay\" INTEGER, "
  79. "\"ldgNight\" INTEGER, "
  80. "\"autoland\" INTEGER, "
  81. "\"secondPilot\" INTEGER, "
  82. "\"thirdPilot\" INTEGER, "
  83. "\"ApproachType\" TEXT, "
  84. "\"FlightNumber\" TEXT, "
  85. "\"Remarks\" TEXT, "
  86. "FOREIGN KEY(\"pic\") REFERENCES \"pilots\"(\"pilot_id\") ON DELETE RESTRICT, "
  87. "FOREIGN KEY(\"acft\") REFERENCES \"tails\"(\"tail_id\") ON DELETE RESTRICT, "
  88. "PRIMARY KEY(\"flight_id\" AUTOINCREMENT) "
  89. ")";
  90. const QString createTableAirports = "CREATE TABLE \"airports\" ( "
  91. "\"airport_id\" INTEGER NOT NULL, "
  92. "\"icao\" TEXT NOT NULL, "
  93. "\"iata\" TEXT, "
  94. "\"name\" TEXT, "
  95. "\"lat\" REAL, "
  96. "\"long\" REAL, "
  97. "\"country\" TEXT, "
  98. "\"alt\" INTEGER, "
  99. "\"utcoffset\" INTEGER, "
  100. "\"tzolson\" TEXT, "
  101. "PRIMARY KEY(\"airport_id\" AUTOINCREMENT) "
  102. ")";
  103. const QString createTableAircraft = "CREATE TABLE \"aircraft\" ( "
  104. "\"aircraft_id\" INTEGER NOT NULL, "
  105. "\"make\" TEXT, "
  106. "\"model\" TEXT, "
  107. "\"variant\" TEXT, "
  108. "\"name\" TEXT, "
  109. "\"iata\" TEXT, "
  110. "\"icao\" TEXT, "
  111. "\"singlepilot\" INTEGER, "
  112. "\"multipilot\" INTEGER, "
  113. "\"singleengine\" INTEGER, "
  114. "\"multiengine\" INTEGER, "
  115. "\"unpowered\" INTEGER, "
  116. "\"piston\" INTEGER, "
  117. "\"turboprop\" INTEGER, "
  118. "\"jet\" INTEGER, "
  119. "\"light\" INTEGER, "
  120. "\"medium\" INTEGER, "
  121. "\"heavy\" INTEGER, "
  122. "\"super\" INTEGER, "
  123. "PRIMARY KEY(\"aircraft_id\" AUTOINCREMENT)"
  124. ")";
  125. const QString createTableChangelog = "CREATE TABLE \"changelog\" ( "
  126. "\"revision\" INTEGER NOT NULL, "
  127. "\"comment\" TEXT, "
  128. "\"date\" NUMERIC, "
  129. "PRIMARY KEY(\"revision\") "
  130. ")";
  131. // Statements for creation of views in the database
  132. const QString createViewDefault = "CREATE VIEW viewDefault AS "
  133. "SELECT flight_id, doft as 'Date', "
  134. "dept AS 'Dept', "
  135. "printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', "
  136. "dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', "
  137. "printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', "
  138. "displayname AS 'Name PIC', "
  139. "make||' '||model||'-'||variant AS 'Type', "
  140. "registration AS 'Registration', "
  141. "FlightNumber AS 'Flight #', "
  142. "Remarks "
  143. "FROM flights "
  144. "INNER JOIN pilots on flights.pic = pilots.pilot_id "
  145. "INNER JOIN tails on flights.acft = tails.tail_id "
  146. "ORDER BY date DESC ";
  147. const QString createViewEASA = "CREATE VIEW viewEASA AS "
  148. "SELECT "
  149. "flight_id, doft as 'Date', "
  150. "dept AS 'Dept', "
  151. "printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', "
  152. "dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', "
  153. "make||' '||model||'-'||variant AS 'Type', "
  154. "registration AS 'Registration', "
  155. "(SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT \"\") AS 'SP SE', "
  156. "(SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT \"\") AS 'SP ME', "
  157. "(SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT \"\") AS 'MP', "
  158. "printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', "
  159. "displayname AS 'Name PIC', "
  160. "ldgDay AS 'L/D', "
  161. "ldgNight AS 'L/N', "
  162. "(SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT \"\") AS 'Night', "
  163. "(SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT \"\") AS 'IFR', "
  164. "(SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT \"\") AS 'PIC', "
  165. "(SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT \"\") AS 'SIC', "
  166. "(SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT \"\") AS 'Dual', "
  167. "(SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT \"\") AS 'FI', "
  168. "Remarks "
  169. "FROM flights "
  170. "INNER JOIN pilots on flights.pic = pilots.pilot_id "
  171. "INNER JOIN tails on flights.acft = tails.tail_id "
  172. "ORDER BY date DESC";
  173. const QString createViewTails = "CREATE VIEW viewTails AS "
  174. "SELECT "
  175. "tail_id AS 'ID', registration AS 'Registration', "
  176. "make||' '||model||'-'||variant AS 'Type', "
  177. "company AS 'Company' "
  178. "FROM tails";
  179. const QString createViewPilots = "CREATE VIEW viewPilots AS "
  180. "SELECT "
  181. "pilot_id AS 'ID', "
  182. "piclastname AS 'Last Name', "
  183. "picfirstname AS 'First Name', company AS 'Company' "
  184. "FROM pilots";
  185. const QString createViewQCompleter = "CREATE VIEW viewQCompleter AS "
  186. "SELECT airport_id, icao, iata, tail_id, registration, pilot_id, "
  187. "piclastname||', '||picfirstname AS 'pilot_name', alias "
  188. "FROM airports "
  189. "LEFT JOIN tails ON airports.airport_id = tails.tail_id "
  190. "LEFT JOIN pilots ON airports.airport_id = pilots.pilot_id";
  191. const QString createViewTotals = "CREATE VIEW viewTotals AS "
  192. "SELECT "
  193. "printf('%02d',CAST(SUM(tblk) AS INT)/60)||':'||printf('%02d',CAST(SUM(tblk) AS INT)%60) AS 'TOTAL', "
  194. "printf('%02d',CAST(SUM(tSPSE) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSPSE) AS INT)%60) AS 'SP SE', "
  195. "printf('%02d',CAST(SUM(tSPME) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSPME) AS INT)%60) AS 'SP ME', "
  196. "printf('%02d',CAST(SUM(tNIGHT) AS INT)/60)||':'||printf('%02d',CAST(SUM(tNIGHT) AS INT)%60) AS 'NIGHT', "
  197. "printf('%02d',CAST(SUM(tIFR) AS INT)/60)||':'||printf('%02d',CAST(SUM(tIFR) AS INT)%60) AS 'IFR', "
  198. "printf('%02d',CAST(SUM(tPIC) AS INT)/60)||':'||printf('%02d',CAST(SUM(tPIC) AS INT)%60) AS 'PIC', "
  199. "printf('%02d',CAST(SUM(tPICUS) AS INT)/60)||':'||printf('%02d',CAST(SUM(tPICUS) AS INT)%60) AS 'PICUS', "
  200. "printf('%02d',CAST(SUM(tSIC) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSIC) AS INT)%60) AS 'SIC', "
  201. "printf('%02d',CAST(SUM(tDual) AS INT)/60)||':'||printf('%02d',CAST(SUM(tDual) AS INT)%60) AS 'DUAL', "
  202. "printf('%02d',CAST(SUM(tFI) AS INT)/60)||':'||printf('%02d',CAST(SUM(tFI) AS INT)%60) AS 'INSTRUCTOR', "
  203. "printf('%02d',CAST(SUM(tSIM) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSIM) AS INT)%60) AS 'SIMULATOR', "
  204. "printf('%02d',CAST(SUM(tMP) AS INT)/60)||':'||printf('%02d',CAST(SUM(tMP) AS INT)%60) AS 'MultPilot', "
  205. "CAST(SUM(toDay) AS INT) AS 'TO Day', CAST(SUM(toNight) AS INT) AS 'TO Night', "
  206. "CAST(SUM(ldgDay) AS INT) AS 'LDG Day', CAST(SUM(ldgNight) AS INT) AS 'LDG Night' "
  207. "FROM flights";
  208. const QStringList tables = {
  209. createTablePilots,
  210. createTableTails,
  211. createTableFlights,
  212. createTableAircraft,
  213. createTableAirports,
  214. createTableChangelog
  215. };
  216. const QStringList views = {
  217. createViewDefault,
  218. createViewEASA,
  219. createViewTails,
  220. createViewPilots,
  221. createViewTotals,
  222. createViewQCompleter
  223. };
  224. const QStringList userTables = {
  225. "flights",
  226. "pilots",
  227. "tails"
  228. };
  229. const QStringList templateTables= {
  230. "aircraft",
  231. "airports",
  232. "changelog"
  233. };
  234. bool DbSetup::createDatabase()
  235. {
  236. /// [George]: Not necessary to heap allocate for such a trivial task
  237. /// TODO: Since you want to be fancy well do it with some cheeky bit operations
  238. /// for the lolz.
  239. QVector<bool> returnValues;
  240. DEB("Creating tables...");
  241. returnValues << createSchemata(tables);
  242. DEB("Creating views...");
  243. returnValues << createSchemata(views);
  244. DEB("Populating tables...");
  245. returnValues << importDefaultData();
  246. for (const auto& allGood : returnValues) {
  247. if (!allGood){
  248. return false;
  249. }
  250. }
  251. DEB("Database successfully created!");
  252. return true;
  253. }
  254. bool DbSetup::importDefaultData()
  255. {
  256. QSqlQuery query;
  257. // reset template tables
  258. for (const auto& table : templateTables) {
  259. //clear tables
  260. query.prepare("DELETE FROM " + table);
  261. if (!query.exec()) {
  262. DEB("Error: " << query.lastError().text());
  263. }
  264. //fill with data from csv
  265. if (!commitData(Csv::read("data/templates/" + table + ".csv"), table)) {
  266. DEB("Error importing data.");
  267. return false;
  268. }
  269. }
  270. return true;
  271. };
  272. /*!
  273. * \brief DbSetup::resetToDefault Empties all user-generated content in the database.
  274. * \return true on success
  275. */
  276. bool DbSetup::resetToDefault()
  277. {
  278. QSqlQuery query;
  279. // clear user tables
  280. for (const auto& table : userTables) {
  281. query.prepare("DELETE FROM " + table);
  282. if (!query.exec()) {
  283. DEB("Error: " << query.lastError().text());
  284. }
  285. }
  286. return true;
  287. }
  288. /*!
  289. * \brief dbSetup::debug prints Database Layout
  290. */
  291. void DbSetup::debug()
  292. {
  293. DEB("Database tables and views: ");
  294. QSqlQuery query;
  295. const QVector<QString> types = { "\"table\"", "\"view\"" };
  296. for (const auto& var : types){
  297. query.prepare("SELECT name FROM sqlite_master WHERE type=" + var);
  298. query.exec();
  299. while (query.next()) {
  300. QString table = query.value(0).toString();
  301. QSqlQuery entries("SELECT COUNT(*) FROM " + table);
  302. entries.next();
  303. DEB("Element " << query.value(0).toString()) << "with"
  304. << entries.value(0).toString() << "rows";
  305. }
  306. }
  307. }
  308. /*!
  309. * \brief dbSetup::createTables Create the required tables for the database
  310. * \return true on success
  311. */
  312. bool DbSetup::createSchemata(const QStringList &statements)
  313. {
  314. QSqlQuery query;
  315. QStringList errors;
  316. for (const auto& statement : statements) {
  317. query.prepare(statement);
  318. query.exec();
  319. if(!query.isActive()) {
  320. errors << statement.section(QLatin1Char(' '),2,2) + " ERROR - " + query.lastError().text();
  321. } else {
  322. DEB("Schema added: " << statement.section(QLatin1Char(' '),2,2));
  323. }
  324. }
  325. if (!errors.isEmpty()) {
  326. DEB("The following errors have ocurred: ");
  327. for (const auto& error : errors) {
  328. DEB(error);
  329. }
  330. return false;
  331. } else {
  332. DEB("All schemas added successfully");
  333. return true;
  334. }
  335. }
  336. /*!
  337. * \brief DbSetup::commitData inserts the data parsed from a csv file into the
  338. * database. The first line of the csv file has to contain the column names
  339. * of the corresponding table in the database.
  340. * \param fromCSV input as parsed from CSV::read()
  341. * \param tableName as in the database
  342. * \return
  343. */
  344. bool DbSetup::commitData(QVector<QStringList> fromCSV, const QString &tableName)
  345. {
  346. DEB("Importing Data to" << tableName);
  347. auto dbLayout = DbInfo();
  348. if (!dbLayout.tables.contains(tableName)){
  349. DEB(tableName << "is not a table in the database. Aborting.");
  350. DEB("Please check input data.");
  351. return false;
  352. }
  353. // create insert statement
  354. QString statement = "INSERT INTO " + tableName + " (";
  355. QString placeholder = ") VALUES (";
  356. for (auto& csvColumn : fromCSV) {
  357. if(dbLayout.format.value(tableName).contains(csvColumn.first())){
  358. statement += csvColumn.first() + ',';
  359. csvColumn.removeFirst();
  360. placeholder.append("?,");
  361. } else {
  362. DEB(csvColumn.first() << "is not a column of " << tableName << "Aborting.");
  363. DEB("Please check input data.");
  364. return false;
  365. }
  366. }
  367. statement.chop(1);
  368. placeholder.chop(1);
  369. placeholder.append(')');
  370. statement.append(placeholder);
  371. /*
  372. * Using exclusive transaction and the loop below is MUCH faster than
  373. * passing the QStringLists to QSqlQuery::addBindValue and using QSqlQuery::execBatch()
  374. */
  375. QSqlQuery query;
  376. query.exec("BEGIN EXCLUSIVE TRANSACTION;");
  377. for (int i = 0; i < fromCSV.first().length(); i++){
  378. query.prepare(statement);
  379. for(int j = 0; j < fromCSV.length(); j++) {
  380. query.addBindValue(fromCSV[j][i]);
  381. }
  382. query.exec();
  383. }
  384. query.exec("COMMIT;"); //commit transaction
  385. if (query.lastError().text().length() > 3) {
  386. DEB("Error:" << query.lastError().text());
  387. return false;
  388. } else {
  389. qDebug() << tableName << "Database successfully updated!";
  390. return true;
  391. }
  392. }