Explorar el Código

Moved Table and View creation staments into sql file

- database_schemata.sql file contains the sql code to create the database layout
- removed the string literals containing the queries from c++ source.
- re-organized qrc ressources
Felix Turo hace 3 años
padre
commit
ef09460908
Se han modificado 7 ficheros con 328 adiciones y 372 borrados
  1. 1 1
      CMakeLists.txt
  2. 288 0
      assets/database/database_schema.sql
  3. 9 0
      assets/database/templates.qrc
  4. 0 8
      assets/templates.qrc
  5. 9 2
      mainwindow.cpp
  6. 15 361
      src/database/adbsetup.cpp
  7. 6 0
      src/opl.h

+ 1 - 1
CMakeLists.txt

@@ -127,7 +127,7 @@ set(PROJECT_SOURCES
 
     # Ressources
     assets/icons.qrc
-    assets/templates.qrc
+    assets/database/templates.qrc
     assets/themes/stylesheets/breeze/breeze.qrc
     assets/themes/stylesheets/qdarkstyle/qdarkstyle.qrc
 

+ 288 - 0
assets/database/database_schema.sql

@@ -0,0 +1,288 @@
+DROP TABLE IF EXISTS 'pilots';
+CREATE TABLE IF NOT EXISTS 'pilots' (
+	'pilot_id'	INTEGER NOT NULL,
+	'lastname'	TEXT NOT NULL,
+	'firstname'	TEXT,
+	'alias'	TEXT,
+	'company'	TEXT,
+	'employeeid'	TEXT,
+	'phone'	TEXT,
+	'email'	TEXT,
+	PRIMARY KEY('pilot_id' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'tails';
+CREATE TABLE IF NOT EXISTS 'tails' (
+	'tail_id'	INTEGER NOT NULL,
+	'registration'	TEXT NOT NULL,
+	'company'	TEXT,
+	'make'	TEXT,
+	'model'	TEXT,
+	'variant'	TEXT,
+	'multipilot'	INTEGER,
+	'multiengine'	INTEGER,
+	'engineType'	INTEGER,
+	'weightClass'	INTEGER,
+	PRIMARY KEY('tail_id' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'flights';
+CREATE TABLE IF NOT EXISTS 'flights' (
+	'flight_id'	INTEGER NOT NULL,
+	'doft'	NUMERIC NOT NULL,
+	'dept'	TEXT NOT NULL,
+	'dest'	TEXT NOT NULL,
+	'tofb'	INTEGER NOT NULL,
+	'tonb'	INTEGER NOT NULL,
+	'pic'	INTEGER NOT NULL,
+	'acft'	INTEGER NOT NULL,
+	'tblk'	INTEGER NOT NULL,
+	'tSPSE'	INTEGER,
+	'tSPME'	INTEGER,
+	'tMP'	INTEGER,
+	'tNIGHT'	INTEGER,
+	'tIFR'	INTEGER,
+	'tPIC'	INTEGER,
+	'tPICUS'	INTEGER,
+	'tSIC'	INTEGER,
+	'tDUAL'	INTEGER,
+	'tFI'	INTEGER,
+	'tSIM'	INTEGER,
+	'pilotFlying'	INTEGER,
+	'toDay'	INTEGER,
+	'toNight'	INTEGER,
+	'ldgDay'	INTEGER,
+	'ldgNight'	INTEGER,
+	'autoland'	INTEGER,
+	'secondPilot'	INTEGER,
+	'thirdPilot'	INTEGER,
+	'approachType'	TEXT,
+	'flightNumber'	TEXT,
+	'remarks'	TEXT,
+	FOREIGN KEY('pic') REFERENCES 'pilots'('pilot_id') ON DELETE RESTRICT,
+	FOREIGN KEY('acft') REFERENCES 'tails'('tail_id') ON DELETE RESTRICT,
+	PRIMARY KEY('flight_id' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'aircraft';
+CREATE TABLE IF NOT EXISTS 'aircraft' (
+	'aircraft_id'	INTEGER NOT NULL,
+	'make'	TEXT,
+	'model'	TEXT,
+	'variant'	TEXT,
+	'name'	TEXT,
+	'iata'	TEXT,
+	'icao'	TEXT,
+	'multipilot'	INTEGER,
+	'multiengine'	INTEGER,
+	'engineType'	INTEGER,
+	'weightClass'	INTEGER,
+	PRIMARY KEY('aircraft_id' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'airports';
+CREATE TABLE IF NOT EXISTS 'airports' (
+	'airport_id'	INTEGER NOT NULL,
+	'icao'	TEXT NOT NULL,
+	'iata'	TEXT,
+	'name'	TEXT,
+	'lat'	REAL,
+	'long'	REAL,
+	'country'	TEXT,
+	'alt'	INTEGER,
+	'utcoffset'	INTEGER,
+	'tzolson'	TEXT,
+	PRIMARY KEY('airport_id' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'currencies';
+CREATE TABLE IF NOT EXISTS 'currencies' (
+	'currency_id'	INTEGER NOT NULL,
+	'description'	TEXT,
+	'expiryDate'	NUMERIC,
+	PRIMARY KEY('currency_id' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'changelog';
+CREATE TABLE IF NOT EXISTS 'changelog' (
+	'revision'	INTEGER NOT NULL,
+	'comment'	TEXT,
+	'date'	NUMERIC,
+	PRIMARY KEY('revision' AUTOINCREMENT)
+);
+DROP TABLE IF EXISTS 'simulators';
+CREATE TABLE IF NOT EXISTS 'simulators' (
+	'session_id'	INTEGER NOT NULL,
+	'date'	NUMERIC NOT NULL,
+	'totalTime'	INTEGER NOT NULL,
+	'deviceType'	TEXT NOT NULL,
+	'aircraftType'	TEXT,
+	'registration'	TEXT,
+	'remarks'	TEXT,
+	PRIMARY KEY('session_id' AUTOINCREMENT)
+);
+
+DROP VIEW IF EXISTS 'viewDefault';
+CREATE VIEW viewDefault AS  
+SELECT flight_id, 
+doft as 'Date',  
+dept AS 'Dept',  
+printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',  
+dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',  
+printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',  
+CASE  WHEN pilot_id = 1 THEN alias  ELSE lastname||', '||substr(firstname, 1, 1)||'.'  END  AS 'Name PIC',  
+CASE  WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant  ELSE make||' '||model  END  AS 'Type',  
+registration AS 'Registration',  
+FlightNumber AS 'Flight #',  
+remarks AS 'Remarks' 
+FROM flights  
+INNER JOIN pilots on flights.pic = pilots.pilot_id  
+INNER JOIN tails on flights.acft = tails.tail_id  
+ORDER BY date DESC;
+
+DROP VIEW IF EXISTS 'viewDefaultSim';
+CREATE VIEW viewDefaultSim AS 
+SELECT flight_id AS 'rowid',   
+doft as 'Date',   
+dept AS 'Dept',   
+printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',   
+dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',   
+printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',   
+CASE  WHEN pilot_id = 1 THEN alias  ELSE lastname||', '||substr(firstname, 1, 1)||'.'  END  AS 'Name PIC',   
+CASE  WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant  ELSE make||' '||model  END  AS 'Type',   
+registration AS 'Registration',    
+null AS 'Sim Type', 
+null AS 'Time of Session', 
+remarks AS 'Remarks' 
+FROM flights   
+INNER JOIN pilots on flights.pic = pilots.pilot_id  
+INNER JOIN tails on flights.acft = tails.tail_id   
+UNION 
+SELECT (session_id * -1), 
+date, 
+null, null, null, null, 
+'SIM', 
+null, 
+aircraftType, 
+registration, 
+deviceType, 
+printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)), 
+remarks 
+FROM simulators 
+ORDER BY date DESC;
+
+DROP VIEW IF EXISTS 'viewEasa';
+CREATE VIEW viewEasa AS  SELECT  flight_id, 
+doft as 'Date',  
+dept AS 'Dept',  
+printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',  
+dest AS 'Dest', 
+printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',  
+CASE  WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant  ELSE make||' '||model  END  AS 'Type',  
+registration AS 'Registration',  
+(SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE',  
+(SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME',  
+(SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP',  
+printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',  
+CASE  WHEN pilot_id = 1 THEN alias  ELSE lastname||', '||substr(firstname, 1, 1)||'.'  END  AS 'Name PIC',  
+ldgDay AS 'L/D',  
+ldgNight AS 'L/N',  
+(SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL)  AS 'Night',  
+(SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL)  AS 'IFR',  
+(SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL)  AS 'PIC',  
+(SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL)  AS 'SIC',  
+(SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL)  AS 'Dual',  
+(SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL)  AS 'FI',  
+remarks AS 'Remarks'  
+FROM flights  
+INNER JOIN pilots on flights.pic = pilots.pilot_id  
+INNER JOIN tails on flights.acft = tails.tail_id  ORDER BY date DESC;
+
+DROP VIEW IF EXISTS 'viewEasaSim';
+CREATE VIEW viewEasaSim AS  SELECT  flight_id, 
+doft as 'Date',    
+dept AS 'Dept',  
+printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',    
+dest AS 'Dest', 
+printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',    
+CASE  WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant  ELSE make||' '||model  END  AS 'Type',    
+registration AS 'Registration',    
+(SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE', 
+(SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME',    
+(SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP',    
+printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',    
+CASE  WHEN pilot_id = 1 THEN alias  ELSE lastname||', '||substr(firstname, 1, 1)||'.'  END  AS 'Name PIC',    
+ldgDay AS 'L/D',    
+ldgNight AS 'L/N',    
+(SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL)  AS 'Night',    
+(SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL)  AS 'IFR',    
+(SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL)  AS 'PIC',    
+(SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL)  AS 'SIC',    
+(SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL)  AS 'Dual',    
+(SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL)  AS 'FI',  
+null AS 'Sim Type',  
+null AS 'Time of Session',  
+remarks AS 'Remarks'    
+FROM flights    
+INNER JOIN pilots on flights.pic = pilots.pilot_id    
+INNER JOIN tails on flights.acft = tails.tail_id    
+UNION  
+SELECT (session_id * -1),  
+date,  
+null,  null,  null,  null,  
+aircraftType,  
+registration,  
+null,  null,  null,  
+'SIM',  
+null,  null,  null,  null,  null,  null,  null,  null,  null,  
+deviceType,  printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)),  
+remarks  
+FROM simulators  
+ORDER BY date DESC;
+
+DROP VIEW IF EXISTS 'viewSimulators';
+CREATE VIEW viewSimulators AS SELECT (session_id * -1),  
+date as 'Date',  
+registration AS 'Registration',   
+aircraftType AS 'Aircraft Type',   
+deviceType 'Sim Type',  
+printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)) AS 'Time of Session',  
+remarks AS 'Remarks'  
+FROM simulators  
+ORDER BY date DESC;
+
+DROP VIEW IF EXISTS 'viewTails';
+CREATE VIEW viewTails AS  
+SELECT  tail_id AS 'ID',  
+registration AS 'Registration',  
+make||' '||model AS 'Type',  
+company AS 'Company'  
+FROM tails WHERE model IS NOT NULL AND variant IS NULL  
+UNION  
+SELECT  tail_id AS 'ID',  
+registration AS 'Registration',  
+make||' '||model||'-'||variant AS 'Type',  
+company AS 'Company'  
+FROM tails WHERE variant IS NOT NULL;
+
+DROP VIEW IF EXISTS 'viewPilots';
+CREATE VIEW viewPilots AS  
+SELECT  pilot_id AS 'ID',  
+lastname AS 'Last Name',  
+firstname AS 'First Name',  
+company AS 'Company'  
+FROM pilots;
+
+DROP VIEW IF EXISTS 'viewTotals';
+CREATE VIEW viewTotals AS  
+SELECT  printf('%02d',CAST(SUM(tblk) AS INT)/60)||':'||printf('%02d',CAST(SUM(tblk) AS INT)%60) AS 'TOTAL',  
+printf('%02d',CAST(SUM(tSPSE) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSPSE) AS INT)%60) AS 'SP SE',  
+printf('%02d',CAST(SUM(tSPME) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSPME) AS INT)%60) AS 'SP ME',  
+printf('%02d',CAST(SUM(tNIGHT) AS INT)/60)||':'||printf('%02d',CAST(SUM(tNIGHT) AS INT)%60) AS 'NIGHT',  
+printf('%02d',CAST(SUM(tIFR) AS INT)/60)||':'||printf('%02d',CAST(SUM(tIFR) AS INT)%60) AS 'IFR',  
+printf('%02d',CAST(SUM(tPIC) AS INT)/60)||':'||printf('%02d',CAST(SUM(tPIC) AS INT)%60) AS 'PIC',  
+printf('%02d',CAST(SUM(tPICUS) AS INT)/60)||':'||printf('%02d',CAST(SUM(tPICUS) AS INT)%60) AS 'PICUS',  
+printf('%02d',CAST(SUM(tSIC) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSIC) AS INT)%60) AS 'SIC',  
+printf('%02d',CAST(SUM(tDual) AS INT)/60)||':'||printf('%02d',CAST(SUM(tDual) AS INT)%60) AS 'DUAL',  
+printf('%02d',CAST(SUM(tFI) AS INT)/60)||':'||printf('%02d',CAST(SUM(tFI) AS INT)%60) AS 'INSTRUCTOR',  
+printf('%02d',CAST(SUM(tSIM) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSIM) AS INT)%60) AS 'SIMULATOR',  
+printf('%02d',CAST(SUM(tMP) AS INT)/60)||':'||printf('%02d',CAST(SUM(tMP) AS INT)%60) AS 'MultPilot',  
+CAST(SUM(toDay) AS INT) AS 'TO Day', 
+CAST(SUM(toNight) AS INT) AS 'TO Night',  
+CAST(SUM(ldgDay) AS INT) AS 'LDG Day', 
+CAST(SUM(ldgNight) AS INT) AS 'LDG Night'  
+FROM flights

+ 9 - 0
assets/database/templates.qrc

@@ -0,0 +1,9 @@
+<RCC>
+    <qresource prefix="/database">
+        <file>templates/aircraft.json</file>
+        <file>templates/airports.json</file>
+        <file>templates/changelog.json</file>
+        <file>templates/currencies.json</file>
+        <file>database_schema.sql</file>
+    </qresource>
+</RCC>

+ 0 - 8
assets/templates.qrc

@@ -1,8 +0,0 @@
-<RCC>
-    <qresource prefix="/templates">
-        <file>database/templates/aircraft.json</file>
-        <file>database/templates/airports.json</file>
-        <file>database/templates/changelog.json</file>
-        <file>database/templates/currencies.json</file>
-    </qresource>
-</RCC>

+ 9 - 2
mainwindow.cpp

@@ -30,8 +30,15 @@
 // Quick and dirty Debug area
 void MainWindow::doDebugStuff()
 {
-    auto nsd = new NewSimDialog(1, this);
-    nsd->exec();
+    QSqlQuery query;
+    QFile f(OPL::Assets::DATABASE_SCHEMA);
+    f.open(QIODevice::ReadOnly);
+    QByteArray filedata = f.readAll();
+
+    auto list = filedata.split(';');
+    for (const auto &string : list)
+        //query.exec(string);
+        LOG << string;
 }
 
 MainWindow::MainWindow(QWidget *parent)

+ 15 - 361
src/database/adbsetup.cpp

@@ -26,358 +26,6 @@ namespace aDbSetup {
 // const auto TEMPLATE_URL = QStringLiteral("https://raw.githubusercontent.com/fiffty-50/openpilotlog/tree/main/assets/database/templates/");
 const static auto TEMPLATE_URL = QStringLiteral("https://raw.githubusercontent.com/fiffty-50/openpilotlog/develop/assets/database/templates/");
 
-
-const static auto CREATE_TABLE_PILOTS = QStringLiteral("CREATE TABLE pilots ( "
-            " pilot_id       INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "
-            " lastname       TEXT    NOT NULL, "
-            " firstname      TEXT, "
-            " alias          TEXT, "
-            " company        TEXT, "
-            " employeeid     TEXT, "
-            " phone          TEXT, "
-            " email          TEXT "
-//            " PRIMARY KEY(pilot_id AUTOINCREMENT)"
-            ")"
-                                                       );
-
-const static auto CREATE_TABLE_TAILS = QStringLiteral("CREATE TABLE tails ("
-            " tail_id        INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,"
-            " registration   TEXT NOT NULL,"
-            " company        TEXT,"
-            " make           TEXT,"
-            " model          TEXT,"
-            " variant        TEXT,"
-            " multipilot     INTEGER,"
-            " multiengine    INTEGER,"
-            " engineType     INTEGER,"
-            " weightClass    INTEGER"
-//            " PRIMARY KEY(tail_id AUTOINCREMENT)"
-            ")"
-                                                      );
-
-const static auto CREATE_TABLE_FLIGHTS = QStringLiteral("CREATE TABLE flights ("
-            " flight_id      INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "
-            " doft           NUMERIC NOT NULL, "
-            " dept           TEXT NOT NULL, "
-            " dest           TEXT NOT NULL, "
-            " tofb           INTEGER NOT NULL, "
-            " tonb           INTEGER NOT NULL, "
-            " pic            INTEGER NOT NULL, "
-            " acft           INTEGER NOT NULL, "
-            " tblk           INTEGER NOT NULL, "
-            " tSPSE          INTEGER, "
-            " tSPME          INTEGER, "
-            " tMP            INTEGER, "
-            " tNIGHT         INTEGER, "
-            " tIFR           INTEGER, "
-            " tPIC           INTEGER, "
-            " tPICUS         INTEGER, "
-            " tSIC           INTEGER, "
-            " tDUAL          INTEGER, "
-            " tFI            INTEGER, "
-            " tSIM           INTEGER, "
-            " pilotFlying    INTEGER, "
-            " toDay          INTEGER, "
-            " toNight        INTEGER, "
-            " ldgDay         INTEGER, "
-            " ldgNight       INTEGER, "
-            " autoland       INTEGER, "
-            " secondPilot    INTEGER, "
-            " thirdPilot     INTEGER, "
-            " approachType   TEXT, "
-            " flightNumber   TEXT, "
-            " remarks        TEXT, "
-            " FOREIGN KEY(pic)  REFERENCES pilots(pilot_id) ON DELETE RESTRICT, "
-            " FOREIGN KEY(acft) REFERENCES tails(tail_id)   ON DELETE RESTRICT "
-//            " PRIMARY KEY(flight_id    AUTOINCREMENT) "
-        ")"
-                                                        );
-
-const static auto CREATE_TABLE_AIRPORTS = QStringLiteral("CREATE TABLE airports ( "
-            " airport_id     INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "
-            " icao           TEXT NOT NULL, "
-            " iata           TEXT, "
-            " name           TEXT, "
-            " lat            REAL, "
-            " long           REAL, "
-            " country        TEXT, "
-            " alt            INTEGER, "
-            " utcoffset      INTEGER, "
-            " tzolson        TEXT "
- //           " PRIMARY KEY(airport_id AUTOINCREMENT) "
-            ")"
-                                                         );
-
-const static auto CREATE_TABLE_AIRCRAFT = QStringLiteral("CREATE TABLE aircraft ("
-            " aircraft_id   INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,"
-            " make          TEXT,"
-            " model         TEXT,"
-            " variant       TEXT,"
-            " name          TEXT,"
-            " iata          TEXT,"
-            " icao          TEXT,"
-            " multipilot    INTEGER,"
-            " multiengine   INTEGER,"
-            " engineType    INTEGER,"
-            " weightClass   INTEGER"
-//            " PRIMARY KEY(aircraft_id AUTOINCREMENT)"
-            ")"
-                                                         );
-
-const static auto CREATE_TABLE_CHANGELOG = QStringLiteral("CREATE TABLE changelog ( "
-            " revision   INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "
-            " comment    TEXT, "
-            " date       NUMERIC "
-//            " PRIMARY KEY(revision) "
-            ")"
-                                                          );
-
-const static auto CREATE_TABLE_CURRENCIES = QStringLiteral("CREATE TABLE currencies ( "
-            " currency_id	INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "
-            " description	TEXT, "
-            " expiryDate     NUMERIC "
-            ")"
-                                                           );
-
-const static auto CREATE_TABLE_SIMULATORS = QStringLiteral("CREATE TABLE simulators ( "
-                                                       " session_id	INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "
-                                                       " date	NUMERIC NOT NULL, "
-                                                       " totalTime	INTEGER NOT NULL, "
-                                                       " deviceType	TEXT NOT NULL, "
-                                                       " aircraftType	TEXT, "
-                                                       " registration	TEXT, "
-                                                       " remarks	TEXT "
-                                                       ")"
-                                                   );
-
-// Statements for creation of views in the database
-const static auto CREATE_VIEW_DEFAULT = QStringLiteral("CREATE VIEW viewDefault AS "
-        " SELECT flight_id, doft as 'Date', "
-        " dept AS 'Dept', "
-        " printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', "
-        " dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', "
-        " printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', "
-        " CASE "
-        " WHEN pilot_id = 1 THEN alias "
-        " ELSE lastname||', '||substr(firstname, 1, 1)||'.' "
-        " END "
-        " AS 'Name PIC', "
-        " CASE "
-        " WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant "
-        " ELSE make||' '||model "
-        " END "
-        " AS 'Type', "
-        " registration AS 'Registration', "
-        " FlightNumber AS 'Flight #', "
-        " remarks AS 'Remarks'"
-        " FROM flights "
-        " INNER JOIN pilots on flights.pic = pilots.pilot_id "
-        " INNER JOIN tails on flights.acft = tails.tail_id "
-        " ORDER BY date DESC ");
-
-const static auto CREATE_VIEW_DEFAULT_SIM = QStringLiteral( "CREATE VIEW viewDefaultSim AS SELECT flight_id AS 'rowid',  "
-        " doft as 'Date',  "
-        " dept AS 'Dept',  "
-        " printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',  "
-        " dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',  "
-        " printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',  "
-        " CASE  WHEN pilot_id = 1 THEN alias  ELSE lastname||', '||substr(firstname, 1, 1)||'.'  END  AS 'Name PIC',  "
-        " CASE  WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant  ELSE make||' '||model  END  AS 'Type',  "
-        " registration AS 'Registration',   "
-        " null AS 'Sim Type',"
-        " null AS 'Time of Session',"
-        " remarks AS 'Remarks'"
-        " FROM flights  "
-        " INNER JOIN pilots on flights.pic = pilots.pilot_id  INNER JOIN tails on flights.acft = tails.tail_id  "
-        " UNION"
-        " SELECT (session_id * -1),"
-        " date,"
-        " null,"
-        " null,"
-        " null,"
-        " null,"
-        " 'SIM',"
-        " null,"
-        " aircraftType,"
-        " registration,"
-        " deviceType,"
-        " printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)),"
-        " remarks"
-        " FROM simulators"
-        " ORDER BY date DESC"
-            );
-
-const static auto CREATE_VIEW_EASA = QStringLiteral("CREATE VIEW viewEasa AS "
-        " SELECT "
-        " flight_id, doft as 'Date', "
-        " dept AS 'Dept', "
-        " printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', "
-        " dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', "
-        " CASE "
-        " WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant "
-        " ELSE make||' '||model "
-        " END "
-        " AS 'Type', "
-        " registration AS 'Registration', "
-        " (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE', "
-        " (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME', "
-        " (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP', "
-        " printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', "
-        " CASE "
-        " WHEN pilot_id = 1 THEN alias "
-        " ELSE lastname||', '||substr(firstname, 1, 1)||'.' "
-        " END "
-        " AS 'Name PIC', "
-        " ldgDay AS 'L/D', "
-        " ldgNight AS 'L/N', "
-        " (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL)  AS 'Night', "
-        " (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL)  AS 'IFR', "
-        " (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL)  AS 'PIC', "
-        " (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL)  AS 'SIC', "
-        " (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL)  AS 'Dual', "
-        " (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL)  AS 'FI', "
-        " remarks AS 'Remarks' "
-        " FROM flights "
-        " INNER JOIN pilots on flights.pic = pilots.pilot_id "
-        " INNER JOIN tails on flights.acft = tails.tail_id "
-        " ORDER BY date DESC"
-                                                    );
-
-const static auto CREATE_VIEW_EASA_SIM = QStringLiteral(" CREATE VIEW viewEasaSim AS "
-            " SELECT  flight_id, doft as 'Date',   "
-            " dept AS 'Dept',  printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',   "
-            " dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',   "
-            " CASE  WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant  ELSE make||' '||model  END  AS 'Type',   "
-            " registration AS 'Registration',   "
-            " (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE',   "
-            " (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME',   "
-            " (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP',   "
-            " printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',   "
-            " CASE  WHEN pilot_id = 1 THEN alias  ELSE lastname||', '||substr(firstname, 1, 1)||'.'  END  AS 'Name PIC',   "
-            " ldgDay AS 'L/D',   "
-            " ldgNight AS 'L/N',   "
-            " (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL)  AS 'Night',   "
-            " (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL)  AS 'IFR',   "
-            " (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL)  AS 'PIC',   "
-            " (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL)  AS 'SIC',   "
-            " (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL)  AS 'Dual',   "
-            " (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL)  AS 'FI', "
-            " null AS 'Sim Type', "
-            " null AS 'Time of Session', "
-            " remarks AS 'Remarks'   "
-            " FROM flights   "
-            " INNER JOIN pilots on flights.pic = pilots.pilot_id   "
-            " INNER JOIN tails on flights.acft = tails.tail_id   "
-            " UNION "
-            " SELECT (session_id * -1), "
-            " date, "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " aircraftType, "
-            " registration, "
-            " null, "
-            " null, "
-            " null, "
-            " 'SIM', "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " null, "
-            " deviceType, "
-            " printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)), "
-            " remarks "
-            " FROM simulators "
-            " ORDER BY date DESC "
-            );
-
-const static auto CREATE_VIEW_SIMULATORS = QStringLiteral (" CREATE VIEW viewSimulators AS SELECT (session_id * -1), "
-                                                           " date as 'Date', "
-                                                           " registration AS 'Registration',  "
-                                                           " aircraftType AS 'Aircraft Type',  "
-                                                           " deviceType 'Sim Type', "
-                                                           " printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)) AS 'Time of Session', "
-                                                           " remarks AS 'Remarks' "
-                                                           " FROM simulators "
-                                                           " ORDER BY date DESC "
-            );
-
-const static auto CREATE_VIEW_TAILS = QStringLiteral("CREATE VIEW viewTails AS "
-        " SELECT "
-        " tail_id AS 'ID', "
-        " registration AS 'Registration', "
-        " make||' '||model AS 'Type', "
-        " company AS 'Company' "
-        " FROM tails WHERE model IS NOT NULL AND variant IS NULL "
-        " UNION "
-        " SELECT "
-        " tail_id AS 'ID', "
-        " registration AS 'Registration', "
-        " make||' '||model||'-'||variant AS 'Type', "
-        " company AS 'Company' "
-        " FROM tails WHERE variant IS NOT NULL");
-
-const static auto CREATE_VIEW_PILOTS = QStringLiteral("CREATE VIEW viewPilots AS "
-        " SELECT "
-        " pilot_id AS 'ID', "
-        " lastname AS 'Last Name', "
-        " firstname AS 'First Name', "
-        " company AS 'Company' "
-        " FROM pilots");
-
-const static auto CREATE_VIEW_QCOMPLETER = QStringLiteral("CREATE VIEW viewQCompleter AS "
-        " SELECT airport_id, icao, iata, tail_id, registration, pilot_id, "
-        " lastname||', '||firstname AS 'pilot_name', alias "
-        " FROM airports "
-        " LEFT JOIN tails ON airports.airport_id = tails.tail_id "
-        " LEFT JOIN pilots ON airports.airport_id = pilots.pilot_id");
-
-const static auto CREATE_VIEW_TOTALS = QStringLiteral("CREATE VIEW viewTotals AS "
-        " SELECT "
-        " printf(\"%02d\",CAST(SUM(tblk) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tblk) AS INT)%60) AS \"TOTAL\", "
-        " printf(\"%02d\",CAST(SUM(tSPSE) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSPSE) AS INT)%60) AS \"SP SE\", "
-        " printf(\"%02d\",CAST(SUM(tSPME) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSPME) AS INT)%60) AS \"SP ME\", "
-        " printf(\"%02d\",CAST(SUM(tNIGHT) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tNIGHT) AS INT)%60) AS \"NIGHT\", "
-        " printf(\"%02d\",CAST(SUM(tIFR) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tIFR) AS INT)%60) AS \"IFR\", "
-        " printf(\"%02d\",CAST(SUM(tPIC) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tPIC) AS INT)%60) AS \"PIC\", "
-        " printf(\"%02d\",CAST(SUM(tPICUS) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tPICUS) AS INT)%60) AS \"PICUS\", "
-        " printf(\"%02d\",CAST(SUM(tSIC) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSIC) AS INT)%60) AS \"SIC\", "
-        " printf(\"%02d\",CAST(SUM(tDual) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tDual) AS INT)%60) AS \"DUAL\", "
-        " printf(\"%02d\",CAST(SUM(tFI) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tFI) AS INT)%60) AS \"INSTRUCTOR\", "
-        " printf(\"%02d\",CAST(SUM(tSIM) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tSIM) AS INT)%60) AS \"SIMULATOR\", "
-        " printf(\"%02d\",CAST(SUM(tMP) AS INT)/60)||\":\"||printf(\"%02d\",CAST(SUM(tMP) AS INT)%60) AS \"MultPilot\", "
-        " CAST(SUM(toDay) AS INT) AS \"TO Day\", CAST(SUM(toNight) AS INT) AS \"TO Night\", "
-        " CAST(SUM(ldgDay) AS INT) AS \"LDG Day\", CAST(SUM(ldgNight) AS INT) AS \"LDG Night\" "
-        " FROM flights");
-
-const static QStringList DATABASE_TABLES = {
-    CREATE_TABLE_PILOTS,
-    CREATE_TABLE_TAILS,
-    CREATE_TABLE_FLIGHTS,
-    CREATE_TABLE_AIRCRAFT,
-    CREATE_TABLE_AIRPORTS,
-    CREATE_TABLE_CURRENCIES,
-    CREATE_TABLE_CHANGELOG,
-    CREATE_TABLE_SIMULATORS,
-};
-const static QStringList DATABASE_VIEWS = {
-    CREATE_VIEW_DEFAULT,
-    CREATE_VIEW_DEFAULT_SIM,
-    CREATE_VIEW_EASA,
-    CREATE_VIEW_EASA_SIM,
-    CREATE_VIEW_SIMULATORS,
-    CREATE_VIEW_TAILS,
-    CREATE_VIEW_PILOTS,
-    CREATE_VIEW_TOTALS,
-    CREATE_VIEW_QCOMPLETER,
-};
-
 const static QStringList USER_TABLES = {
     QStringLiteral("flights"),
     QStringLiteral("pilots"),
@@ -392,19 +40,25 @@ const static QStringList TEMPLATE_TABLES= {
 
 bool createDatabase()
 {
+    // Read Database layout from sql file
+    QFile f(OPL::Assets::DATABASE_SCHEMA);
+    f.open(QIODevice::ReadOnly);
+    QByteArray filedata = f.readAll();
+    // create individual queries for each table/view
+    auto list = filedata.split(';');
+
+    // Commit
     QSqlQuery q;
     QVector<QSqlError> errors;
     // Create Tables
-    for (const auto &query_string : DATABASE_TABLES) {
-        q.prepare(query_string);
-        if (!q.exec())
-            errors.append(q.lastError());
-    }
-    // Create Views
-    for (const auto &query_string : DATABASE_VIEWS) {
+    for (const auto &query_string : list) {
         q.prepare(query_string);
-        if (!q.exec())
+        if (!q.exec()) {
             errors.append(q.lastError());
+            LOG << "Unable to execute query: ";
+            LOG << q.lastQuery();
+            LOG << q.lastError();
+        }
     }
 
     aDB->updateLayout();
@@ -481,7 +135,7 @@ bool importTemplateData(bool use_local_ressources)
         QString error_message("Error importing data ");
 
         if (use_local_ressources) {
-            data_to_commit = AJson::readFileToDoc(QLatin1String(":templates/database/templates/")
+            data_to_commit = AJson::readFileToDoc(QLatin1String(":database/templates/")
                                       + table_name + QLatin1String(".json")).array();
             error_message.append(QLatin1String(" (ressource) "));
         } else {

+ 6 - 0
src/opl.h

@@ -306,6 +306,12 @@ static const auto NULL_TIME_hhmm         = QStringLiteral("00:00");
 
 namespace Assets {
 
+static const auto DATABASE_SCHEMA               = QStringLiteral(":/database/database_schema.sql");
+static const auto DATABASE_TEMPLATE_AIRCRAFT    = QStringLiteral(":/database/templates/aircraft.json");
+static const auto DATABASE_TEMPLATE_AIRPORT     = QStringLiteral(":/database/templates/airports.json");
+static const auto DATABASE_TEMPLATE_CHANGELOG   = QStringLiteral(":/database/templates/changelog.json");
+static const auto DATABASE_TEMPLATE_CURRENCIES  = QStringLiteral(":/database/templates/currencies.json");
+
 static const auto LOGO                          = QStringLiteral(":/icons/opl-icons/logos/logo_text.png");
 static const auto ICON_MAIN                     = QStringLiteral(":/icons/opl-icons/app/icon_main.png");
 static const auto ICON_APPICON_LINUX            = QStringLiteral(":/icons/opl-icons/app/icon_linux.svg");