adatabasesetup.cpp 19 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485
  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 "adatabasesetup.h"
  19. #include "src/database/adatabase.h"
  20. #include "src/testing/adebug.h"
  21. #include "src/functions/areadcsv.h"
  22. #include "src/classes/astandardpaths.h"
  23. #include "src/classes/adownload.h"
  24. #include "src/oplconstants.h"
  25. #include "src/functions/adatetime.h"
  26. // Statements for creation of database tables, Revision 15
  27. const auto createTablePilots = QStringLiteral("CREATE TABLE pilots ( "
  28. " pilot_id INTEGER NOT NULL, "
  29. " lastname TEXT NOT NULL, "
  30. " firstname TEXT, "
  31. " alias TEXT, "
  32. " company TEXT, "
  33. " employeeid TEXT, "
  34. " phone TEXT, "
  35. " email TEXT, "
  36. " PRIMARY KEY(pilot_id AUTOINCREMENT)"
  37. ")");
  38. const auto createTableTails = QStringLiteral("CREATE TABLE tails ("
  39. " tail_id INTEGER NOT NULL,"
  40. " registration TEXT NOT NULL,"
  41. " company TEXT,"
  42. " make TEXT,"
  43. " model TEXT,"
  44. " variant TEXT,"
  45. " multipilot INTEGER,"
  46. " multiengine INTEGER,"
  47. " engineType INTEGER,"
  48. " weightClass INTEGER,"
  49. " PRIMARY KEY(tail_id AUTOINCREMENT)"
  50. ")");
  51. const auto createTableFlights = QStringLiteral("CREATE TABLE flights ("
  52. " flight_id INTEGER NOT NULL, "
  53. " doft NUMERIC NOT NULL, "
  54. " dept TEXT NOT NULL, "
  55. " dest TEXT NOT NULL, "
  56. " tofb INTEGER NOT NULL, "
  57. " tonb INTEGER NOT NULL, "
  58. " pic INTEGER NOT NULL, "
  59. " acft INTEGER NOT NULL, "
  60. " tblk INTEGER NOT NULL, "
  61. " tSPSE INTEGER, "
  62. " tSPME INTEGER, "
  63. " tMP INTEGER, "
  64. " tNIGHT INTEGER, "
  65. " tIFR INTEGER, "
  66. " tPIC INTEGER, "
  67. " tPICUS INTEGER, "
  68. " tSIC INTEGER, "
  69. " tDUAL INTEGER, "
  70. " tFI INTEGER, "
  71. " tSIM INTEGER, "
  72. " pilotFlying INTEGER, "
  73. " toDay INTEGER, "
  74. " toNight INTEGER, "
  75. " ldgDay INTEGER, "
  76. " ldgNight INTEGER, "
  77. " autoland INTEGER, "
  78. " secondPilot INTEGER, "
  79. " thirdPilot INTEGER, "
  80. " approachType TEXT, "
  81. " flightNumber TEXT, "
  82. " remarks TEXT, "
  83. " FOREIGN KEY(pic) REFERENCES pilots(pilot_id) ON DELETE RESTRICT, "
  84. " FOREIGN KEY(acft) REFERENCES tails(tail_id) ON DELETE RESTRICT, "
  85. " PRIMARY KEY(flight_id AUTOINCREMENT) "
  86. ")");
  87. const auto createTableAirports = QStringLiteral("CREATE TABLE airports ( "
  88. " airport_id INTEGER NOT NULL, "
  89. " icao TEXT NOT NULL, "
  90. " iata TEXT, "
  91. " name TEXT, "
  92. " lat REAL, "
  93. " long REAL, "
  94. " country TEXT, "
  95. " alt INTEGER, "
  96. " utcoffset INTEGER, "
  97. " tzolson TEXT, "
  98. " PRIMARY KEY(airport_id AUTOINCREMENT) "
  99. ")");
  100. const auto createTableAircraft = QStringLiteral("CREATE TABLE aircraft ("
  101. " aircraft_id INTEGER NOT NULL,"
  102. " make TEXT,"
  103. " model TEXT,"
  104. " variant TEXT,"
  105. " name TEXT,"
  106. " iata TEXT,"
  107. " icao TEXT,"
  108. " multipilot INTEGER,"
  109. " multiengine INTEGER,"
  110. " engineType INTEGER,"
  111. " weightClass INTEGER,"
  112. " PRIMARY KEY(aircraft_id AUTOINCREMENT)"
  113. ")");
  114. const auto createTableChangelog = QStringLiteral("CREATE TABLE changelog ( "
  115. " revision INTEGER NOT NULL, "
  116. " comment TEXT, "
  117. " date NUMERIC, "
  118. " PRIMARY KEY(revision) "
  119. ")");
  120. // Statements for creation of views in the database
  121. const auto createViewDefault = QStringLiteral("CREATE VIEW viewDefault AS "
  122. " SELECT flight_id, doft as 'Date', "
  123. " dept AS 'Dept', "
  124. " printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', "
  125. " dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', "
  126. " printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', "
  127. " CASE "
  128. " WHEN pilot_id = 1 THEN alias "
  129. " ELSE lastname||', '||substr(firstname, 1, 1)||'.' "
  130. " END "
  131. " AS 'Name PIC', "
  132. " make||' '||model||'-'||variant AS 'Type', "
  133. " registration AS 'Registration', "
  134. " FlightNumber AS 'Flight #', "
  135. " remarks AS 'Remarks'"
  136. " FROM flights "
  137. " INNER JOIN pilots on flights.pic = pilots.pilot_id "
  138. " INNER JOIN tails on flights.acft = tails.tail_id "
  139. " ORDER BY date DESC ");
  140. const auto createViewEASA = QStringLiteral("CREATE VIEW viewEASA AS "
  141. " SELECT "
  142. " flight_id, doft as 'Date', "
  143. " dept AS 'Dept', "
  144. " printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', "
  145. " dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', "
  146. " make||' '||model||'-'||variant AS 'Type', "
  147. " registration AS 'Registration', "
  148. " (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE', "
  149. " (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME', "
  150. " (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP', "
  151. " printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', "
  152. " CASE "
  153. " WHEN pilot_id = 1 THEN alias "
  154. " ELSE lastname||', '||substr(firstname, 1, 1)||'.' "
  155. " END "
  156. " AS 'Name PIC', "
  157. " ldgDay AS 'L/D', "
  158. " ldgNight AS 'L/N', "
  159. " (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL) AS 'Night', "
  160. " (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL) AS 'IFR', "
  161. " (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL) AS 'PIC', "
  162. " (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL) AS 'SIC', "
  163. " (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL) AS 'Dual', "
  164. " (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL) AS 'FI', "
  165. " remarks AS 'Remarks' "
  166. " FROM flights "
  167. " INNER JOIN pilots on flights.pic = pilots.pilot_id "
  168. " INNER JOIN tails on flights.acft = tails.tail_id "
  169. " ORDER BY date DESC");
  170. const auto createViewTails = QStringLiteral("CREATE VIEW viewTails AS "
  171. " SELECT "
  172. " tail_id AS 'ID', "
  173. " registration AS 'Registration', "
  174. " make||' '||model AS 'Type', "
  175. " company AS 'Company' "
  176. " FROM tails WHERE model IS NOT NULL AND variant IS NULL "
  177. " UNION "
  178. " SELECT "
  179. " tail_id AS 'ID', "
  180. " registration AS 'Registration', "
  181. " make||' '||model||'-'||variant AS 'Type', "
  182. " company AS 'Company' "
  183. " FROM tails WHERE variant IS NOT NULL");
  184. const auto createViewPilots = QStringLiteral("CREATE VIEW viewPilots AS "
  185. " SELECT "
  186. " pilot_id AS 'ID', "
  187. " lastname AS 'Last Name', "
  188. " firstname AS 'First Name', "
  189. " company AS 'Company' "
  190. " FROM pilots");
  191. const auto createViewQCompleter = QStringLiteral("CREATE VIEW viewQCompleter AS "
  192. " SELECT airport_id, icao, iata, tail_id, registration, pilot_id, "
  193. " lastname||', '||firstname AS 'pilot_name', alias "
  194. " FROM airports "
  195. " LEFT JOIN tails ON airports.airport_id = tails.tail_id "
  196. " LEFT JOIN pilots ON airports.airport_id = pilots.pilot_id");
  197. const auto createViewTotals = QStringLiteral("CREATE VIEW viewTotals AS "
  198. " SELECT "
  199. " printf(\"%02d\",CAST(SUM(tblk) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tblk) AS INT)%60) AS \"TOTAL\", "
  200. " printf(\"%02d\",CAST(SUM(tSPSE) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSPSE) AS INT)%60) AS \"SP SE\", "
  201. " printf(\"%02d\",CAST(SUM(tSPME) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSPME) AS INT)%60) AS \"SP ME\", "
  202. " printf(\"%02d\",CAST(SUM(tNIGHT) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tNIGHT) AS INT)%60) AS \"NIGHT\", "
  203. " printf(\"%02d\",CAST(SUM(tIFR) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tIFR) AS INT)%60) AS \"IFR\", "
  204. " printf(\"%02d\",CAST(SUM(tPIC) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tPIC) AS INT)%60) AS \"PIC\", "
  205. " printf(\"%02d\",CAST(SUM(tPICUS) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tPICUS) AS INT)%60) AS \"PICUS\", "
  206. " printf(\"%02d\",CAST(SUM(tSIC) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSIC) AS INT)%60) AS \"SIC\", "
  207. " printf(\"%02d\",CAST(SUM(tDual) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tDual) AS INT)%60) AS \"DUAL\", "
  208. " printf(\"%02d\",CAST(SUM(tFI) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tFI) AS INT)%60) AS \"INSTRUCTOR\", "
  209. " printf(\"%02d\",CAST(SUM(tSIM) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSIM) AS INT)%60) AS \"SIMULATOR\", "
  210. " printf(\"%02d\",CAST(SUM(tMP) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tMP) AS INT)%60) AS \"MultPilot\", "
  211. " CAST(SUM(toDay) AS INT) AS \"TO Day\", CAST(SUM(toNight) AS INT) AS \"TO Night\", "
  212. " CAST(SUM(ldgDay) AS INT) AS \"LDG Day\", CAST(SUM(ldgNight) AS INT) AS \"LDG Night\" "
  213. " FROM flights");
  214. const QStringList tables = {
  215. createTablePilots,
  216. createTableTails,
  217. createTableFlights,
  218. createTableAircraft,
  219. createTableAirports,
  220. createTableChangelog
  221. };
  222. const QStringList views = {
  223. createViewDefault,
  224. createViewEASA,
  225. createViewTails,
  226. createViewPilots,
  227. createViewTotals,
  228. createViewQCompleter,
  229. };
  230. const QStringList userTables = {
  231. "flights",
  232. "pilots",
  233. "tails"
  234. };
  235. const QStringList templateTables= {
  236. "aircraft",
  237. "airports",
  238. "changelog"
  239. };
  240. bool ADataBaseSetup::createDatabase()
  241. {
  242. DEB << "Creating tables...";
  243. if (!createSchemata(tables)) {
  244. DEB << "Creating tables has failed.";
  245. return false;
  246. }
  247. DEB << "Creating views...";
  248. if (!createSchemata(views)) {
  249. DEB << "Creating views failed.";
  250. return false;
  251. }
  252. aDB->updateLayout();
  253. DEB << "Database successfully created!";
  254. return true;
  255. }
  256. bool ADataBaseSetup::downloadTemplates()
  257. {
  258. QDir template_dir(AStandardPaths::directory(AStandardPaths::Templates));
  259. DEB << template_dir;
  260. for (const auto& table : templateTables) {
  261. QEventLoop loop;
  262. ADownload* dl = new ADownload;
  263. QObject::connect(dl, &ADownload::done, &loop, &QEventLoop::quit );
  264. dl->setTarget(QUrl(TEMPLATE_URL % table % QStringLiteral(".csv")));
  265. dl->setFileName(template_dir.absoluteFilePath(table % QStringLiteral(".csv")));
  266. dl->download();
  267. dl->deleteLater();
  268. loop.exec(); // event loop waits for download done signal before allowing loop to continue
  269. QFileInfo downloaded_file(template_dir.filePath(table % QStringLiteral(".csv")));
  270. if (downloaded_file.size() == 0)
  271. return false; // ssl/network error
  272. }
  273. return true;
  274. }
  275. bool ADataBaseSetup::backupOldData()
  276. {
  277. auto database_file = aDB->databaseFile;
  278. if(!database_file.exists()) {
  279. DEB << "No Database to backup, returning.";
  280. return true;
  281. }
  282. auto date_string = ADateTime::toString(QDateTime::currentDateTime(),
  283. Opl::Datetime::Backup);
  284. auto backup_dir = AStandardPaths::directory(AStandardPaths::Backup);
  285. auto backup_name = database_file.baseName() + "_bak_" + date_string + ".db";
  286. QFile file(aDB->databaseFile.absoluteFilePath());
  287. if (!file.rename(backup_dir.absoluteFilePath(backup_name))) {
  288. DEB << "Unable to backup old database.";
  289. return false;
  290. }
  291. DEB << "Backed up old database as: " << backup_name;
  292. return true;
  293. }
  294. bool ADataBaseSetup::importDefaultData(bool use_local_data)
  295. {
  296. QSqlQuery query;
  297. // reset template tables
  298. for (const auto& table_name : templateTables) {
  299. //clear tables
  300. query.prepare("DELETE FROM " + table_name);
  301. if (!query.exec()) {
  302. DEB << "Error: " << query.lastError().text();
  303. return false;
  304. }
  305. // Prepare data
  306. QVector<QStringList> data_to_commit;
  307. QString error_message("Error importing data ");
  308. if (use_local_data) {
  309. data_to_commit = aReadCsv(QStringLiteral(":templates/database/templates/")
  310. + table_name + QStringLiteral(".csv"));
  311. error_message.append(" (local) ");
  312. } else {
  313. data_to_commit = aReadCsv(AStandardPaths::directory(
  314. AStandardPaths::Templates).absoluteFilePath(
  315. table_name + QStringLiteral(".csv")));
  316. error_message.append(" (remote) ");
  317. }
  318. //fill with data from csv
  319. if (!commitData(data_to_commit, table_name)) {
  320. DEB << error_message;
  321. return false;
  322. }
  323. }
  324. return true;
  325. };
  326. /*!
  327. * \brief DbSetup::resetToDefault Empties all user-generated content in the database.
  328. * \return true on success
  329. */
  330. bool ADataBaseSetup::resetToDefault()
  331. {
  332. QSqlQuery query;
  333. // clear user tables
  334. for (const auto& table : userTables) {
  335. query.prepare("DELETE FROM " + table);
  336. if (!query.exec()) {
  337. DEB << "Error: " << query.lastError().text();
  338. }
  339. }
  340. return true;
  341. }
  342. /*!
  343. * \brief dbSetup::debug prints Database Layout
  344. */
  345. void ADataBaseSetup::debug()
  346. {
  347. DEB << "Database tables and views: ";
  348. QSqlQuery query;
  349. const QVector<QString> types = { "table", "view" };
  350. for (const auto& var : types){
  351. query.prepare("SELECT name FROM sqlite_master WHERE type=" + var);
  352. query.exec();
  353. while (query.next()) {
  354. QString table = query.value(0).toString();
  355. QSqlQuery entries("SELECT COUNT(*) FROM " + table);
  356. entries.next();
  357. DEB << "Element " << query.value(0).toString() << "with"
  358. << entries.value(0).toString() << "rows";
  359. }
  360. }
  361. }
  362. /*!
  363. * \brief dbSetup::createTables Create the required tables for the database
  364. * \return true on success
  365. */
  366. bool ADataBaseSetup::createSchemata(const QStringList &statements)
  367. {
  368. QSqlQuery query;
  369. QStringList errors;
  370. for (const auto& statement : statements) {
  371. query.prepare(statement);
  372. query.exec();
  373. if(!query.isActive()) {
  374. errors << statement.section(QLatin1Char(' '),2,2) + " ERROR - " + query.lastError().text();
  375. DEB << "Query: " << query.lastQuery();
  376. continue;
  377. }
  378. DEB << "Schema added: " << statement.section(QLatin1Char(' '), 2, 2);
  379. }
  380. if (!errors.isEmpty()) {
  381. DEB_SRC << "The following errors have ocurred: ";
  382. for (const auto& error : qAsConst(errors)) {
  383. DEB_RAW << error;
  384. }
  385. return false;
  386. }
  387. DEB << "All schemas added successfully";
  388. return true;
  389. }
  390. /*!
  391. * \brief DbSetup::commitData inserts the data parsed from a csv file into the
  392. * database. The first line of the csv file has to contain the column names
  393. * of the corresponding table in the database.
  394. * \param fromCSV input as parsed from CSV::read()
  395. * \param tableName as in the database
  396. * \return
  397. */
  398. bool ADataBaseSetup::commitData(QVector<QStringList> from_csv, const QString &table_name)
  399. {
  400. aDB->updateLayout();
  401. if (!aDB->getTableNames().contains(table_name)){
  402. DEB << table_name << "is not a table in the database. Aborting.";
  403. DEB << "Please check input data.";
  404. return false;
  405. }
  406. // create insert statement
  407. QString statement = "INSERT INTO " + table_name + " (";
  408. QString placeholder = ") VALUES (";
  409. for (auto& csvColumn : from_csv) {
  410. if(aDB->getTableColumns(table_name).contains(csvColumn.first())) {
  411. statement += csvColumn.first() + ',';
  412. csvColumn.removeFirst();
  413. placeholder.append("?,");
  414. } else {
  415. DEB << csvColumn.first() << "is not a column of " << table_name << "Aborting.";
  416. DEB << "Please check input data.";
  417. return false;
  418. }
  419. }
  420. statement.chop(1);
  421. placeholder.chop(1);
  422. placeholder.append(')');
  423. statement.append(placeholder);
  424. /*
  425. * Using exclusive transaction and the loop below is MUCH faster than
  426. * passing the QStringLists to QSqlQuery::addBindValue and using QSqlQuery::execBatch()
  427. */
  428. QSqlQuery query;
  429. query.exec("BEGIN EXCLUSIVE TRANSACTION;");
  430. for (int i = 0; i < from_csv.first().length(); i++){
  431. query.prepare(statement);
  432. for(int j = 0; j < from_csv.length(); j++) {
  433. from_csv[j][i] == QString("") ? // make sure NULL is committed for empty values
  434. query.addBindValue(QVariant(QString()))
  435. : query.addBindValue(from_csv[j][i]);
  436. //query.addBindValue(fromCSV[j][i]);
  437. }
  438. query.exec();
  439. }
  440. query.exec("COMMIT;"); //commit transaction
  441. if (query.lastError().text().length() > 3) {
  442. DEB << "Error:" << query.lastError().text();
  443. return false;
  444. } else {
  445. qDebug() << table_name << "Database successfully updated!";
  446. return true;
  447. }
  448. }