Browse Source

Initial implementation SQLite

Maurits van der Schee 8 years ago
parent
commit
f7ff4ef2fa
4 changed files with 284 additions and 1 deletions
  1. 188
    0
      api.php
  2. 80
    0
      tests/blog_sqlite.sql
  3. 1
    1
      tests/config.php.dist
  4. 15
    0
      tests/tests.php

+ 188
- 0
api.php View File

@@ -569,6 +569,194 @@ class SQLServer implements DatabaseInterface {
569 569
 	}
570 570
 }
571 571
 
572
+class SQLite implements DatabaseInterface {
573
+
574
+	protected $db;
575
+	protected $queries;
576
+
577
+	public function __construct() {
578
+		$this->queries = array(
579
+			'list_tables'=>'SELECT
580
+					"name", ""
581
+				FROM
582
+					"sys/tables"',
583
+			'reflect_table'=>'SELECT
584
+					"name"
585
+				FROM
586
+					"sys/tables"
587
+				WHERE
588
+					"name"=?',
589
+			'reflect_pk'=>'SELECT
590
+					"name"
591
+				FROM
592
+					"sys/columns"
593
+				WHERE
594
+					"pk"=1 AND
595
+					"self"=?',
596
+			'reflect_belongs_to'=>'SELECT
597
+					"self", "from",
598
+					"table", "to"
599
+				FROM
600
+					"sys/foreign_keys"
601
+				WHERE
602
+					"self" = ? AND
603
+					"table" IN ? AND
604
+					? like "%" AND
605
+					? like "%"',
606
+			'reflect_has_many'=>'SELECT
607
+					"self", "from",
608
+					"table", "to"
609
+				FROM
610
+					"sys/foreign_keys"
611
+				WHERE
612
+					"self" IN ? AND
613
+					"table" = ? AND
614
+					? like "%" AND
615
+					? like "%"',
616
+			'reflect_habtm'=>'SELECT
617
+					k1."self", k1."from",
618
+					k1."table", k1."to",
619
+					k2."self", k2."from",
620
+					k2."table", k2."to"
621
+				FROM
622
+					"sys/foreign_keys" k1,
623
+					"sys/foreign_keys" k2
624
+				WHERE
625
+					? like "%" AND
626
+					? like "%" AND
627
+					? like "%" AND
628
+					? like "%" AND
629
+					k1."self" = k2."self" AND
630
+					k1."table" = ? AND
631
+					k2."table" IN ?'
632
+		);
633
+	}
634
+
635
+	public function getSql($name) {
636
+		return isset($this->queries[$name])?$this->queries[$name]:false;
637
+	}
638
+
639
+	public function connect($hostname,$username,$password,$database,$port,$socket,$charset) {
640
+		$this->db = new SQLite3($database);
641
+		// optimizations
642
+		$this->db->querySingle('PRAGMA synchronous = NORMAL');
643
+		$this->db->querySingle('PRAGMA foreign_keys = on');
644
+		$reflection = $this->db->querySingle('SELECT name FROM sqlite_master WHERE type = "table" and name like "sys/%"');
645
+		if (!$reflection) {
646
+			//create reflection tables
647
+			$this->query('CREATE table "sys/version" ("version" integer)');
648
+			$this->query('CREATE table "sys/tables" ("name" text)');
649
+			$this->query('CREATE table "sys/columns" ("self" text,"cid" integer,"name" text,"type" integer,"notnull" integer,"dflt_value" integer,"pk" integer)');
650
+			$this->query('CREATE table "sys/foreign_keys" ("self" text,"id" integer,"seq" integer,"table" text,"from" text,"to" text,"on_update" text,"on_delete" text,"match" text)');
651
+		}
652
+		$version = $this->db->querySingle('pragma schema_version');
653
+		if ($version != $this->db->querySingle('SELECT "version" from "sys/version"')) {
654
+			// update version data
655
+			$this->query('DELETE FROM "sys/version"');
656
+			$this->query('INSERT into "sys/version" ("version") VALUES (?)',array($version));
657
+			// update tables data
658
+			$this->query('DELETE FROM "sys/tables"');
659
+			$result = $this->query('SELECT * FROM sqlite_master WHERE type = "table" and name not like "sys/%" and name<>"sqlite_sequence"');
660
+			$tables = array();
661
+			while ($row = $this->fetchAssoc($result)) {
662
+				$tables[] = $row['name'];
663
+				$this->query('INSERT into "sys/tables" ("name") VALUES (?)',array($row['name']));
664
+			}
665
+			// update columns and foreign_keys data
666
+			$this->query('DELETE FROM "sys/columns"');
667
+			$this->query('DELETE FROM "sys/foreign_keys"');
668
+			foreach ($tables as $table) {
669
+				$result = $this->query('pragma table_info(!)',array($table));
670
+				while ($row = $this->fetchRow($result)) {
671
+					array_unshift($row, $table);
672
+					$this->query('INSERT into "sys/columns" ("self","cid","name","type","notnull","dflt_value","pk") VALUES (?,?,?,?,?,?,?)',$row);
673
+				}
674
+				$result = $this->query('pragma foreign_key_list(!)',array($table));
675
+				while ($row = $this->fetchRow($result)) {
676
+					array_unshift($row, $table);
677
+					$this->query('INSERT into "sys/foreign_keys" ("self","id","seq","table","from","to","on_update","on_delete","match") VALUES (?,?,?,?,?,?,?,?,?)',$row);
678
+				}
679
+			}
680
+		}
681
+	}
682
+
683
+	public function query($sql,$params=array()) {
684
+		$db = $this->db;
685
+		$sql = preg_replace_callback('/\!|\?/', function ($matches) use (&$db,&$params) {
686
+			$param = array_shift($params);
687
+			if ($matches[0]=='!') return preg_replace('/[^a-zA-Z0-9\-_=<> ]/','',$param);
688
+			if (is_array($param)) return '('.implode(',',array_map(function($v) use (&$db) {
689
+				return "'".$db->escapeString($v)."'";
690
+			},$param)).')';
691
+			if (is_object($param) && $param->type=='base64') {
692
+				return "'".$db->escapeString(base64_decode($param->data))."'";
693
+			}
694
+			if ($param===null) return 'NULL';
695
+			return "'".$db->escapeString($param)."'";
696
+		}, $sql);
697
+		//echo "\n$sql\n";
698
+		try {	$result=$db->query($sql); } catch(\Exception $e) { $result=null; }
699
+		return $result;
700
+	}
701
+
702
+	public function fetchAssoc($result) {
703
+		$values = $result->fetchArray(SQLITE3_ASSOC);
704
+		if ($values) $values = array_map(function($v){ return is_null($v)?null:(string)$v; },$values);
705
+		return $values;
706
+	}
707
+
708
+	public function fetchRow($result) {
709
+		$values = $result->fetchArray(SQLITE3_NUM);
710
+		if ($values) $values = array_map(function($v){ return is_null($v)?null:(string)$v; },$values);
711
+		return $values;
712
+	}
713
+
714
+	public function insertId($result) {
715
+		return $this->db->lastInsertRowID();
716
+	}
717
+
718
+	public function affectedRows($result) {
719
+		return $this->db->changes();
720
+	}
721
+
722
+	public function close($result) {
723
+		return $result->finalize();
724
+	}
725
+
726
+	public function fetchFields($result) {
727
+		$values = $result->fetchArray();
728
+		$fields = array();
729
+		for($i = 0; $i < $result->numColumns() ; $i++){
730
+			$tab = array();
731
+			$tab['type'] = $result->columnType($i);
732
+			$tab['name'] = $result->columnName($i);
733
+			$fields[strtolower($tab['name'])] = (object)$tab;
734
+		}
735
+		return $fields;
736
+	}
737
+
738
+	public function addLimitToSql($sql,$limit,$offset) {
739
+		return "$sql LIMIT $limit OFFSET $offset";
740
+	}
741
+
742
+	public function likeEscape($string) {
743
+		return addcslashes($string,'%_');
744
+	}
745
+
746
+	public function isBinaryType($field) {
747
+		return ($field->type==4);
748
+	}
749
+
750
+	public function base64Encode($string) {
751
+		return base64_encode($string);
752
+	}
753
+
754
+	public function getDefaultCharset() {
755
+		return 'utf8';
756
+	}
757
+
758
+}
759
+
572 760
 class PHP_CRUD_API {
573 761
 
574 762
 	protected $db;

+ 80
- 0
tests/blog_sqlite.sql View File

@@ -0,0 +1,80 @@
1
+-- Adminer 4.2.4 SQLite 3 dump
2
+
3
+DROP TABLE IF EXISTS "categories";
4
+CREATE TABLE "categories" (
5
+  "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT,
6
+  "name" text(255) NOT NULL,
7
+  "icon" blob NULL
8
+);
9
+
10
+INSERT INTO "categories" ("id", "name", "icon") VALUES (1,	'anouncement',	NULL);
11
+INSERT INTO "categories" ("id", "name", "icon") VALUES (2,	'article',	NULL);
12
+
13
+DROP TABLE IF EXISTS "comments";
14
+CREATE TABLE "comments" (
15
+  "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT,
16
+  "post_id" integer NOT NULL,
17
+  "message" text NOT NULL,
18
+  FOREIGN KEY ("post_id") REFERENCES "posts" ("id")
19
+);
20
+
21
+CREATE INDEX "comments_post_id" ON "comments" ("post_id");
22
+
23
+INSERT INTO "comments" ("id", "post_id", "message") VALUES (1,	1,	'great');
24
+INSERT INTO "comments" ("id", "post_id", "message") VALUES (2,	1,	'fantastic');
25
+INSERT INTO "comments" ("id", "post_id", "message") VALUES (3,	2,	'thank you');
26
+INSERT INTO "comments" ("id", "post_id", "message") VALUES (4,	2,	'awesome');
27
+
28
+DROP TABLE IF EXISTS "post_tags";
29
+CREATE TABLE "post_tags" (
30
+  "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT,
31
+  "post_id" integer NOT NULL,
32
+  "tag_id" integer NOT NULL,
33
+  FOREIGN KEY ("tag_id") REFERENCES "tags" ("id"),
34
+  FOREIGN KEY ("post_id") REFERENCES "posts" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT
35
+);
36
+
37
+CREATE UNIQUE INDEX "post_tags_post_id_tag_id" ON "post_tags" ("post_id", "tag_id");
38
+
39
+INSERT INTO "post_tags" ("id", "post_id", "tag_id") VALUES (1,	1,	1);
40
+INSERT INTO "post_tags" ("id", "post_id", "tag_id") VALUES (2,	1,	2);
41
+INSERT INTO "post_tags" ("id", "post_id", "tag_id") VALUES (3,	2,	1);
42
+INSERT INTO "post_tags" ("id", "post_id", "tag_id") VALUES (4,	2,	2);
43
+
44
+DROP TABLE IF EXISTS "posts";
45
+CREATE TABLE "posts" (
46
+  "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT,
47
+  "user_id" integer NOT NULL,
48
+  "category_id" integer NOT NULL,
49
+  "content" text NOT NULL,
50
+  FOREIGN KEY ("user_id") REFERENCES "users" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
51
+  FOREIGN KEY ("category_id") REFERENCES "categories" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT
52
+);
53
+
54
+CREATE INDEX "posts_user_id" ON "posts" ("user_id");
55
+
56
+CREATE INDEX "posts_category_id" ON "posts" ("category_id");
57
+
58
+INSERT INTO "posts" ("id", "user_id", "category_id", "content") VALUES (1,	1,	1,	'blog started');
59
+INSERT INTO "posts" ("id", "user_id", "category_id", "content") VALUES (2,	1,	2,	'It works!');
60
+
61
+DROP TABLE IF EXISTS "tags";
62
+CREATE TABLE `tags` (
63
+  `id` integer NOT NULL PRIMARY KEY AUTOINCREMENT,
64
+  `name` text(255) NOT NULL
65
+);
66
+
67
+INSERT INTO "tags" ("id", "name") VALUES (1,	'funny');
68
+INSERT INTO "tags" ("id", "name") VALUES (2,	'important');
69
+
70
+DROP TABLE IF EXISTS "users";
71
+CREATE TABLE `users` (
72
+  `id` integer NOT NULL PRIMARY KEY AUTOINCREMENT,
73
+  `username` text(255) NOT NULL,
74
+  `password` text(255) NOT NULL
75
+);
76
+
77
+INSERT INTO "users" ("id", "username", "password") VALUES (1,	'user1',	'pass1');
78
+INSERT INTO "users" ("id", "username", "password") VALUES (2,	'user2',	'pass2');
79
+
80
+--

+ 1
- 1
tests/config.php.dist View File

@@ -2,7 +2,7 @@
2 2
 
3 3
 class PHP_CRUD_API_Config
4 4
 {
5
-	public static $dbengine='MySQL';             // 'MySQL', 'SQLServer' or 'PostgreSQL'
5
+	public static $dbengine='MySQL';             // 'MySQL', 'SQLServer', 'PostgreSQL' or 'SQLite'
6 6
 	public static $hostname='{{test_hostname}}'; // 'localhost' for mysql or '(Local)' for mssql
7 7
 	public static $username='{{test_username}}'; // May be empty on mssql
8 8
 	public static $password='{{test_password}}'; // May be empty on mssql

+ 15
- 0
tests/tests.php View File

@@ -164,6 +164,21 @@ class PHP_CRUD_API_Test extends PHPUnit_Framework_TestCase
164 164
 			}
165 165
 			pg_close($db);
166 166
 
167
+		} elseif ($dbengine == 'SQLite') {
168
+
169
+			$db = new SQLite3($database);
170
+			if (!$db) {
171
+				die("Could not open '$database' SQLite database: ".SQLite3::lastErrorMsg().' ('.SQLite3::lastErrorCode().")\n");
172
+			}
173
+			$queries = preg_split('/;\s*\n/', file_get_contents($fixture));
174
+			array_pop($queries);
175
+			foreach ($queries as $i=>$query) {
176
+				if (!$db->query($query.';')) {
177
+					$i++;
178
+					die("Loading '$fixture' failed on statemement #$i with error:\n".$db->lastErrorCode().': '.$db->lastErrorMsg()."\n");
179
+				}
180
+			}
181
+			$db->close();
167 182
 		}
168 183
 	}
169 184
 

Loading…
Cancel
Save