From 90c86f25f45b6df3ee5e99870296100d6ae08057 Mon Sep 17 00:00:00 2001 From: Markus Birth Date: Tue, 19 Dec 2017 22:36:42 +0100 Subject: [PATCH] Separated initial data from db schema. Minor optimisations. --- bin/initdb.sh | 1 + lib/TclUpdates/SQLiteReader.php | 30 +++++----- sql/basedata.sql | 86 +++++++++++++++++++++++++++++ sql/dbschema.sql | 98 ++------------------------------- 4 files changed, 106 insertions(+), 109 deletions(-) create mode 100644 sql/basedata.sql diff --git a/bin/initdb.sh b/bin/initdb.sh index b54d614..bb3dfbb 100755 --- a/bin/initdb.sh +++ b/bin/initdb.sh @@ -1,3 +1,4 @@ #!/bin/sh MYDIR=$(dirname "$(readlink -f "$0")") sqlite3 "${MYDIR}/../otadb.db3" < "${MYDIR}/../sql/dbschema.sql" +sqlite3 "${MYDIR}/../otadb.db3" < "${MYDIR}/../sql/basedata.sql" diff --git a/lib/TclUpdates/SQLiteReader.php b/lib/TclUpdates/SQLiteReader.php index d66be78..92dfd42 100644 --- a/lib/TclUpdates/SQLiteReader.php +++ b/lib/TclUpdates/SQLiteReader.php @@ -33,7 +33,7 @@ class SQLiteReader public function getAllKnownRefs() { - $sql = 'SELECT DISTINCT ref FROM devices ORDER BY ref;'; + $sql = 'SELECT DISTINCT curef FROM devices ORDER BY curef;'; $sqlresult = $this->pdo->query($sql); $result = array(); foreach ($sqlresult as $row) { @@ -52,13 +52,13 @@ class SQLiteReader public function getAllVariants() { - $sql = 'SELECT f.name, m.name, d.ref, d.name FROM families f LEFT JOIN models m ON f.familyId=m.familyId LEFT JOIN devices d ON m.modelId=d.modelId;'; + $sql = 'SELECT f.name, m.name, d.curef, d.name FROM families f LEFT JOIN models m ON f.familyId=m.familyId LEFT JOIN devices d ON m.modelId=d.modelId;'; $sqlresult = $this->pdo->query($sql); $result = array(); foreach ($sqlresult as $row) { $family = $row[0]; $model = $row[1]; - $ref = $row[2]; + $curef = $row[2]; $variant = $row[3]; if (!isset($result[$family])) { $result[$family] = array(); @@ -66,26 +66,26 @@ class SQLiteReader if (!isset($result[$family][$model])) { $result[$family][$model] = array(); } - $result[$family][$model][$ref] = $variant; + $result[$family][$model][$curef] = $variant; } return $result; } public function getAllVariantsFlat() { - $sql = 'SELECT f.name AS family, m.name AS model, d.ref, d.name AS variant FROM families f LEFT JOIN models m ON f.familyId=m.familyId LEFT JOIN devices d ON m.modelId=d.modelId;'; + $sql = 'SELECT f.name AS family, m.name AS model, d.curef, d.name AS variant FROM families f LEFT JOIN models m ON f.familyId=m.familyId LEFT JOIN devices d ON m.modelId=d.modelId;'; $sqlresult = $this->pdo->query($sql); $result = array(); foreach ($sqlresult->fetchAll(\PDO::FETCH_ASSOC) as $row) { - $result[$row['ref']] = $row['family'] . ' ' . $row['model']; + $result[$row['curef']] = $row['family'] . ' ' . $row['model']; if (strlen($row['variant'])>0) { - $result[$row['ref']] .= ' (' . $row['variant'] . ')'; + $result[$row['curef']] .= ' (' . $row['variant'] . ')'; } } return $result; } - public function getAllUpdates($ref, $which = self::BOTH) + public function getAllUpdates($curef, $which = self::BOTH) { $sql = 'SELECT * FROM updates u LEFT JOIN files f ON u.file_sha1=f.sha1 WHERE curef=?'; if ($which == self::OTA_ONLY) { @@ -94,12 +94,12 @@ class SQLiteReader $sql .= ' AND fv IS null'; } $stmt = $this->pdo->prepare($sql); - $ok = $stmt->execute(array($ref)); + $ok = $stmt->execute(array($curef)); $result = $stmt->fetchAll(\PDO::FETCH_ASSOC); return $result; } - public function getLatestUpdate($ref, $which = self::BOTH) + public function getLatestUpdate($curef, $which = self::BOTH) { $sql = 'SELECT * FROM updates u LEFT JOIN files f ON u.file_sha1=f.sha1 WHERE curef=?'; if ($which == self::OTA_ONLY) { @@ -109,7 +109,7 @@ class SQLiteReader } $sql .= ' ORDER BY tv DESC, fv DESC LIMIT 1'; $stmt = $this->pdo->prepare($sql); - $ok = $stmt->execute(array($ref)); + $ok = $stmt->execute(array($curef)); $result = $stmt->fetchAll(\PDO::FETCH_ASSOC); if (count($result) == 1) { $result = reset($result); @@ -117,14 +117,14 @@ class SQLiteReader return $result; } - public function getAllVersionsForRef($ref = null, $which = self::BOTH) + public function getAllVersionsForRef($curef = null, $which = self::BOTH) { $sql = 'SELECT fv, tv FROM updates u LEFT JOIN files f ON u.file_sha1=f.sha1'; $where_arr = array(); $params_arr = array(); - if (!is_null($ref)) { + if (!is_null($curef)) { $where_arr[] = 'curef=?'; - $params_arr[] = $ref; + $params_arr[] = $curef; } if ($which == self::OTA_ONLY) { $where_arr[] = 'fv IS NOT null'; @@ -151,7 +151,7 @@ class SQLiteReader public function getAllVersionsForModel($model) { - $sql = 'SELECT fv, tv FROM models m LEFT JOIN devices d ON m.modelId=d.modelId LEFT JOIN updates u ON d.ref=u.curef LEFT JOIN files f ON u.file_sha1=f.sha1 WHERE m.name=?'; + $sql = 'SELECT fv, tv FROM models m LEFT JOIN devices d ON m.modelId=d.modelId LEFT JOIN updates u ON d.curef=u.curef LEFT JOIN files f ON u.file_sha1=f.sha1 WHERE m.name=?'; $stmt = $this->pdo->prepare($sql); $ok = $stmt->execute(array($model)); $result = $stmt->fetchAll(\PDO::FETCH_ASSOC); diff --git a/sql/basedata.sql b/sql/basedata.sql new file mode 100644 index 0000000..381bcd2 --- /dev/null +++ b/sql/basedata.sql @@ -0,0 +1,86 @@ +PRAGMA journal_mode=WAL; +PRAGMA foreign_keys=on; + +BEGIN TRANSACTION; + +INSERT OR IGNORE INTO "families" VALUES (1, "KEYone"); +INSERT OR IGNORE INTO "families" VALUES (2, "Motion"); + +INSERT OR IGNORE INTO "models" VALUES ( 1, 1, "BBB100-1"); +INSERT OR IGNORE INTO "models" VALUES ( 2, 1, "BBB100-2"); +INSERT OR IGNORE INTO "models" VALUES ( 3, 1, "BBB100-3"); +INSERT OR IGNORE INTO "models" VALUES ( 4, 1, "BBB100-4/-5"); +INSERT OR IGNORE INTO "models" VALUES ( 5, 1, "BBB100-6"); +INSERT OR IGNORE INTO "models" VALUES ( 6, 1, "BBB100-7"); +INSERT OR IGNORE INTO "models" VALUES ( 7, 2, "BBD100-1"); +INSERT OR IGNORE INTO "models" VALUES ( 8, 2, "BBD100-2"); +INSERT OR IGNORE INTO "models" VALUES ( 9, 2, "BBD100-6"); + +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-001", 1, "Unlocked USA"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-003", 1, "Bell"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-005", 1, "Rogers"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-007", 1, "Telus"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-009", 1, "Hong Kong"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-010", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-013", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-017", 1, "Caribbean"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-020", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-021", 1, "Hong Kong?"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-023", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-024", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-027", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-029", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-033", 1, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-036", 1, "AT&T"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-039", 1, "Black KEYone Canada"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-040", 1, "Black KEYone Malaysia"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-041", 1, "Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-042", 1, "Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-043", 1, "Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-044", 1, "Black KEYone Hong Kong"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-047", 1, "Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-051", 1, "Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63116-055", 1, "Black KEYone Korea"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-003", 2, "Unlocked UK"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-011", 2, "Unlocked EMEA"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-015", 2, "NL, Belgium"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-017", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-019", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-021", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-023", 2, "AZERTY Belgium"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-025", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-027", 2, "QWERTY UAE"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-028", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-029", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-034", 2, "UAE?"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-035", 2, "Black KEYone UK"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-036", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-037", 2, "Black KEYone Middle East"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-039", 2, "Black KEYone Europe"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-040", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-041", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-042", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-043", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-044", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-047", 2, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-703", 2, "Prerelease"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-704", 2, "Prerelease"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63117-717", 2, "Prerelease Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63118-001", 3, "Unlocked"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63118-003", 3, "Sprint"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63734-001", 4, "Unlocked -4"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63734-002", 4, "Unlocked -4"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63734-003", 4, "Unlocked -5"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63734-004", 4, "Unlocked -5"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63763-001", 5, "Unlocked"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63763-002", 5, "Unlocked Black KEYone"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63764-001", 6, "Unlocked"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63737-003", 7, "UK"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63737-007", 7, "Europe"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63737-009", 7, "Europe"); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63739-009", 8, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63739-010", 8, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63753-002", 9, ""); +INSERT OR IGNORE INTO "devices" VALUES ("PRD-63753-003", 9, ""); + +COMMIT; diff --git a/sql/dbschema.sql b/sql/dbschema.sql index 68b8ecf..fcee030 100644 --- a/sql/dbschema.sql +++ b/sql/dbschema.sql @@ -3,111 +3,23 @@ PRAGMA foreign_keys=on; CREATE TABLE "families" ( "familyId" INTEGER PRIMARY KEY AUTOINCREMENT, - "name" TEXT -- e.g. KEYone, Motion + "name" TEXT UNIQUE -- e.g. KEYone, Motion ); --- Needs SQLite 3.7 or newer -INSERT INTO "families" ("name") VALUES - ("KEYone"), -- familyId 1 - ("Motion") -- familyId 2 -; CREATE TABLE "models" ( "modelId" INTEGER PRIMARY KEY AUTOINCREMENT, "familyId" INTEGER REFERENCES "families" ("familyId"), - "name" TEXT -- e.g. BBB100-1 + "name" TEXT UNIQUE -- e.g. BBB100-1 ); --- Needs SQLite 3.7 or newer -INSERT INTO "models" ("familyId", "name") VALUES - (1, "BBB100-1"), -- modelId 1 - (1, "BBB100-2"), -- modelId 2 - (1, "BBB100-3"), -- modelId 3 - (1, "BBB100-4/-5"), -- modelId 4 - (1, "BBB100-6"), -- modelId 5 - (1, "BBB100-7"), -- modelId 6 - (2, "BBD100-1"), -- modelId 7 - (2, "BBD100-2"), -- modelId 8 - (2, "BBD100-6") -- modelId 9 -; - CREATE TABLE "devices" ( - "deviceId" INTEGER PRIMARY KEY AUTOINCREMENT, - "ref" TEXT, -- PRD number + "curef" TEXT UNIQUE PRIMARY KEY, -- PRD number "modelId" INTEGER REFERENCES "models" ("modelId"), "name" TEXT -- e.g. Unlocked USA, Black KEYone ); --- Needs SQLite 3.7 or newer -INSERT INTO "devices" ("ref", "modelId", "name") VALUES - ("PRD-63116-001", 1, "Unlocked USA"), - ("PRD-63116-003", 1, "Bell"), - ("PRD-63116-005", 1, "Rogers"), - ("PRD-63116-007", 1, "Telus"), - ("PRD-63116-009", 1, "Hong Kong"), - ("PRD-63116-010", 1, ""), - ("PRD-63116-013", 1, ""), - ("PRD-63116-017", 1, "Caribbean"), - ("PRD-63116-020", 1, ""), - ("PRD-63116-021", 1, "Hong Kong?"), - ("PRD-63116-023", 1, ""), - ("PRD-63116-024", 1, ""), - ("PRD-63116-027", 1, ""), - ("PRD-63116-029", 1, ""), - ("PRD-63116-033", 1, ""), - ("PRD-63116-036", 1, "AT&T"), - ("PRD-63116-039", 1, "Black KEYone Canada"), - ("PRD-63116-040", 1, "Black KEYone Malaysia"), - ("PRD-63116-041", 1, "Black KEYone"), - ("PRD-63116-042", 1, "Black KEYone"), - ("PRD-63116-043", 1, "Black KEYone"), - ("PRD-63116-044", 1, "Black KEYone Hong Kong"), - ("PRD-63116-047", 1, "Black KEYone"), - ("PRD-63116-051", 1, "Black KEYone"), - ("PRD-63116-055", 1, "Black KEYone Korea"), - ("PRD-63117-003", 2, "Unlocked UK"), - ("PRD-63117-011", 2, "Unlocked EMEA"), - ("PRD-63117-015", 2, "NL, Belgium"), - ("PRD-63117-017", 2, ""), - ("PRD-63117-019", 2, ""), - ("PRD-63117-021", 2, ""), - ("PRD-63117-023", 2, "AZERTY Belgium"), - ("PRD-63117-025", 2, ""), - ("PRD-63117-027", 2, "QWERTY UAE"), - ("PRD-63117-028", 2, ""), - ("PRD-63117-029", 2, ""), - ("PRD-63117-034", 2, "UAE?"), - ("PRD-63117-035", 2, "Black KEYone UK"), - ("PRD-63117-036", 2, ""), - ("PRD-63117-037", 2, "Black KEYone Middle East"), - ("PRD-63117-039", 2, "Black KEYone Europe"), - ("PRD-63117-040", 2, ""), - ("PRD-63117-041", 2, ""), - ("PRD-63117-042", 2, ""), - ("PRD-63117-043", 2, ""), - ("PRD-63117-044", 2, ""), - ("PRD-63117-047", 2, ""), - ("PRD-63117-703", 2, "Prerelease"), - ("PRD-63117-704", 2, "Prerelease"), - ("PRD-63117-717", 2, "Prerelease Black KEYone"), - ("PRD-63118-001", 3, "Unlocked"), - ("PRD-63118-003", 3, "Sprint"), - ("PRD-63734-001", 4, "Unlocked -4"), - ("PRD-63734-002", 4, "Unlocked -4"), - ("PRD-63734-003", 4, "Unlocked -5"), - ("PRD-63734-004", 4, "Unlocked -5"), - ("PRD-63763-001", 5, "Unlocked"), - ("PRD-63763-002", 5, "Unlocked Black KEYone"), - ("PRD-63764-001", 6, "Unlocked"), - ("PRD-63737-003", 7, "UK"), - ("PRD-63737-007", 7, "Europe"), - ("PRD-63737-009", 7, "Europe"), - ("PRD-63739-009", 8, ""), - ("PRD-63739-010", 8, ""), - ("PRD-63753-002", 9, ""), - ("PRD-63753-003", 9, "") -; - +-- we only care about the first file for now CREATE TABLE "files" ( "sha1" TEXT UNIQUE PRIMARY KEY, -- checksum of file "file_name" TEXT, -- filename of file @@ -120,8 +32,6 @@ CREATE TABLE "files" ( "published_last" INTEGER -- stamp of latest pubdate ); --- we only care about the first file for now --- a separate "files" table might get introduced later CREATE TABLE "updates" ( "updateId" INTEGER PRIMARY KEY AUTOINCREMENT, "curef" TEXT, -- PRD number