Added PostgreSQL support

This commit is contained in:
Maurits van der Schee 2015-10-18 02:18:01 +02:00
commit d22830ba7d
3 changed files with 198 additions and 135 deletions

163
api.php
View file

@ -109,57 +109,89 @@ class MySQL_CRUD_API extends REST_CRUD_API {
return (($field->flags & 128) && ($field->type==252)); return (($field->flags & 128) && ($field->type==252));
} }
protected function base64_encode($string) {
return base64_encode($string);
}
} }
class PgSQL_CRUD_API extends REST_CRUD_API { class PgSQL_CRUD_API extends REST_CRUD_API {
protected $queries = array( protected $queries = array(
'reflect_table'=>'SELECT "TABLE_NAME" FROM "INFORMATION_SCHEMA"."TABLES" WHERE "TABLE_NAME" LIKE ? AND "TABLE_SCHEMA" = ?', 'reflect_table'=>'select "table_name" from "information_schema"."tables" where "table_name" like ? and "table_catalog" = ?',
'reflect_pk'=>'SELECT "COLUMN_NAME" FROM "INFORMATION_SCHEMA"."COLUMNS" WHERE "COLUMN_KEY" = \'PRI\' AND "TABLE_NAME" = ? AND "TABLE_SCHEMA" = ?', 'reflect_pk'=>'select
'reflect_belongs_to'=>'SELECT "column_name"
"TABLE_NAME","COLUMN_NAME", from
"REFERENCED_TABLE_NAME","REFERENCED_COLUMN_NAME" "information_schema"."table_constraints" tc, "information_schema"."key_column_usage" ku
FROM where
"INFORMATION_SCHEMA"."KEY_COLUMN_USAGE" tc."constraint_type" = \'PRIMARY KEY\' and
WHERE tc."constraint_name" = ku."constraint_name" and
"TABLE_NAME" = ? AND ku."table_name" = ? and
"REFERENCED_TABLE_NAME" IN ? AND ku."table_catalog" = ?',
"TABLE_SCHEMA" = ? AND 'reflect_belongs_to'=>'select
"REFERENCED_TABLE_SCHEMA" = ?', cu1."table_name",cu1."column_name",
'reflect_has_many'=>'SELECT cu2."table_name",cu2."column_name"
"TABLE_NAME","COLUMN_NAME", from
"REFERENCED_TABLE_NAME","REFERENCED_COLUMN_NAME" "information_schema".referential_constraints rc,
FROM "information_schema".key_column_usage cu1,
"INFORMATION_SCHEMA"."KEY_COLUMN_USAGE" "information_schema".key_column_usage cu2
WHERE where
"TABLE_NAME" IN ? AND cu1."constraint_name" = rc."constraint_name" and
"REFERENCED_TABLE_NAME" = ? AND cu2."constraint_name" = rc."unique_constraint_name" and
"TABLE_SCHEMA" = ? AND cu1."table_name" = ? and
"REFERENCED_TABLE_SCHEMA" = ?', cu2."table_name" in ? and
'reflect_habtm'=>'SELECT cu1."table_catalog" = ? and
k1."TABLE_NAME", k1."COLUMN_NAME", cu2."table_catalog" = ?',
k1."REFERENCED_TABLE_NAME", k1."REFERENCED_COLUMN_NAME", 'reflect_has_many'=>'select
k2."TABLE_NAME", k2."COLUMN_NAME", cu1."table_name",cu1."column_name",
k2."REFERENCED_TABLE_NAME", k2."REFERENCED_COLUMN_NAME" cu2."table_name",cu2."column_name"
FROM from
"INFORMATION_SCHEMA"."KEY_COLUMN_USAGE" k1, "INFORMATION_SCHEMA"."KEY_COLUMN_USAGE" k2 "information_schema".referential_constraints rc,
WHERE "information_schema".key_column_usage cu1,
k1."TABLE_SCHEMA" = ? AND "information_schema".key_column_usage cu2
k2."TABLE_SCHEMA" = ? AND where
k1."REFERENCED_TABLE_SCHEMA" = ? AND cu1."constraint_name" = rc."constraint_name" and
k2."REFERENCED_TABLE_SCHEMA" = ? AND cu2."constraint_name" = rc."unique_constraint_name" and
k1."TABLE_NAME" = k2."TABLE_NAME" AND cu1."table_name" in ? and
k1."REFERENCED_TABLE_NAME" = ? AND cu2."table_name" = ? and
k2."REFERENCED_TABLE_NAME" IN ?' cu1."table_catalog" = ? and
cu2."table_catalog" = ?',
'reflect_habtm'=>'select
cua1."table_name",cua1."column_name",
cua2."table_name",cua2."column_name",
cub1."table_name",cub1."column_name",
cub2."table_name",cub2."column_name"
from
"information_schema".referential_constraints rca,
"information_schema".referential_constraints rcb,
"information_schema".key_column_usage cua1,
"information_schema".key_column_usage cua2,
"information_schema".key_column_usage cub1,
"information_schema".key_column_usage cub2
where
cua1."constraint_name" = rca."constraint_name" and
cua2."constraint_name" = rca."unique_constraint_name" and
cub1."constraint_name" = rcb."constraint_name" and
cub2."constraint_name" = rcb."unique_constraint_name" and
cua1."table_catalog" = ? and
cub1."table_catalog" = ? and
cua2."table_catalog" = ? and
cub2."table_catalog" = ? and
cua1."table_name" = cub1."table_name" and
cua2."table_name" = ? and
cub2."table_name" in ?'
); );
protected function connectDatabase($hostname,$username,$password,$database,$port,$socket,$charset) { protected function connectDatabase($hostname,$username,$password,$database,$port,$socket,$charset) {
$e = function ($v) { return str_replace(array('\'','\\'),array('\\\'','\\\\'),$v); }; $e = function ($v) { return str_replace(array('\'','\\'),array('\\\'','\\\\'),$v); };
$conn_string = "host='".$e($hostname)."' port=5432 dbname=test user=lamb password=bar options='--client_encoding=UTF8'"; $hostname = $e($hostname);
$port = ($port?:5432)+0;
$database = $database;
$username = $e($username);
$password = $e($password);
$charset = $e($charset);
$conn_string = "host='$hostname' port=$port dbname='$database' user='$username' password='$password' options='--client_encoding=$charset'";
$db = pg_connect($conn_string); $db = pg_connect($conn_string);
return $db; return $db;
} }
@ -168,40 +200,51 @@ class PgSQL_CRUD_API extends REST_CRUD_API {
$param = array_shift($params); $param = array_shift($params);
if ($matches[0]=='!') return preg_replace('/[^a-zA-Z0-9\-_=<>]/','',$param); if ($matches[0]=='!') return preg_replace('/[^a-zA-Z0-9\-_=<>]/','',$param);
if (is_array($param)) return '('.implode(',',array_map(function($v) use (&$db) { if (is_array($param)) return '('.implode(',',array_map(function($v) use (&$db) {
return "'".mysqli_real_escape_string($db,$v)."'"; return "'".pg_escape_string($db,$v)."'";
},$param)).')'; },$param)).')';
if (is_object($param) && $param->type=='base64') { if (is_object($param) && $param->type=='base64') {
return "x'".bin2hex(base64_decode($param->data))."'"; return "'\x".bin2hex(base64_decode($param->data))."'";
} }
if ($param===null) return 'NULL'; if ($param===null) return 'NULL';
return "'".mysqli_real_escape_string($db,$param)."'"; return "'".pg_escape_string($db,$param)."'";
}, $sql); }, $sql);
if (strtoupper(substr($sql,0,6))=='INSERT') {
$sql .= ' RETURNING id;';
}
//echo "\n$sql\n"; //echo "\n$sql\n";
return mysqli_query($db,$sql); return @pg_query($db,$sql);
} }
protected function fetch_assoc($result) { protected function fetch_assoc($result) {
return mysqli_fetch_assoc($result); return pg_fetch_assoc($result);
} }
protected function fetch_row($result) { protected function fetch_row($result) {
return mysqli_fetch_row($result); return pg_fetch_row($result);
} }
protected function insert_id($db,$result) { protected function insert_id($db,$result) {
return mysqli_insert_id($db); list($id) = pg_fetch_row($result);
return (int)$id;
} }
protected function affected_rows($db,$result) { protected function affected_rows($db,$result) {
return mysqli_affected_rows($db); return pg_affected_rows($result);
} }
protected function close($result) { protected function close($result) {
return mysqli_free_result($result); return pg_free_result($result);
} }
protected function fetch_fields($result) { protected function fetch_fields($result) {
return mysqli_fetch_fields($result); $fields = array();
for($i=0;$i<pg_num_fields($result);$i++) {
$field = array();
$field['name'] = pg_field_name($result,$i);
$field['type'] = pg_field_type($result,$i);
$fields[$i] = (object)$field;
}
return $fields;
} }
protected function add_limit_to_sql($sql,$limit,$offset) { protected function add_limit_to_sql($sql,$limit,$offset) {
@ -213,8 +256,11 @@ class PgSQL_CRUD_API extends REST_CRUD_API {
} }
protected function is_binary_type($field) { protected function is_binary_type($field) {
//echo "$field->name: $field->type ($field->flags)\n"; return $field->type == 'bytea';
return (($field->flags & 128) && ($field->type==252)); }
protected function base64_encode($string) {
return base64_encode(hex2bin(substr($string,2)));
} }
} }
@ -396,6 +442,10 @@ class MsSQL_CRUD_API extends REST_CRUD_API {
return ($field->type>=-4 && $field->type<=-2); return ($field->type>=-4 && $field->type<=-2);
} }
protected function base64_encode($string) {
return base64_encode($string);
}
} }
class REST_CRUD_API { class REST_CRUD_API {
@ -510,7 +560,6 @@ class REST_CRUD_API {
} }
} }
protected function startOutput($callback) { protected function startOutput($callback) {
if (isset($_SERVER['REQUEST_METHOD'])) { if (isset($_SERVER['REQUEST_METHOD'])) {
header('Access-Control-Allow-Origin: *'); header('Access-Control-Allow-Origin: *');
@ -589,7 +638,7 @@ class REST_CRUD_API {
$object = $this->fetch_assoc($result); $object = $this->fetch_assoc($result);
foreach ($this->fetch_fields($result) as $field) { foreach ($this->fetch_fields($result) as $field) {
if ($this->is_binary_type($field) && $object[$field->name]) { if ($this->is_binary_type($field) && $object[$field->name]) {
$object[$field->name] = base64_encode($object[$field->name]); $object[$field->name] = $this->base64_encode($object[$field->name]);
} }
} }
$this->close($result); $this->close($result);
@ -808,7 +857,7 @@ class REST_CRUD_API {
} }
foreach ($base64 as $k=>$v) { foreach ($base64 as $k=>$v) {
if ($v && $row[$k]) { if ($v && $row[$k]) {
$row[$k] = base64_encode($row[$k]); $row[$k] = $this->base64_encode($row[$k]);
} }
} }
echo json_encode($row); echo json_encode($row);
@ -870,7 +919,7 @@ class REST_CRUD_API {
} }
foreach ($base64 as $k=>$v) { foreach ($base64 as $k=>$v) {
if ($v && $row[$k]) { if ($v && $row[$k]) {
$row[$k] = base64_encode($row[$k]); $row[$k] = $this->base64_encode($row[$k]);
} }
} }
echo json_encode($row); echo json_encode($row);

View file

@ -29,12 +29,23 @@ SET default_tablespace = '';
SET default_with_oids = false; SET default_with_oids = false;
--
-- Drop everything
--
DROP TABLE IF EXISTS categories CASCADE;
DROP TABLE IF EXISTS comments CASCADE;
DROP TABLE IF EXISTS post_tags CASCADE;
DROP TABLE IF EXISTS posts CASCADE;
DROP TABLE IF EXISTS tags CASCADE;
DROP TABLE IF EXISTS users CASCADE;
-- --
-- Name: categories; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- Name: categories; Type: TABLE; Schema: public; Owner: postgres; Tablespace:
-- --
CREATE TABLE categories ( CREATE TABLE categories (
id integer NOT NULL, id serial NOT NULL,
name character varying(255) NOT NULL, name character varying(255) NOT NULL,
icon bytea icon bytea
); );
@ -47,8 +58,8 @@ ALTER TABLE public.categories OWNER TO postgres;
-- --
CREATE TABLE comments ( CREATE TABLE comments (
id integer NOT NULL, id serial NOT NULL,
post_id integer NOT NULL, post_id serial NOT NULL,
message character varying(255) NOT NULL message character varying(255) NOT NULL
); );
@ -60,9 +71,9 @@ ALTER TABLE public.comments OWNER TO postgres;
-- --
CREATE TABLE post_tags ( CREATE TABLE post_tags (
id integer NOT NULL, id serial NOT NULL,
post_id integer NOT NULL, post_id serial NOT NULL,
tag_id integer NOT NULL tag_id serial NOT NULL
); );
@ -73,9 +84,9 @@ ALTER TABLE public.post_tags OWNER TO postgres;
-- --
CREATE TABLE posts ( CREATE TABLE posts (
id integer NOT NULL, id serial NOT NULL,
user_id integer NOT NULL, user_id serial NOT NULL,
category_id integer NOT NULL, category_id serial NOT NULL,
content character varying(255) NOT NULL content character varying(255) NOT NULL
); );
@ -87,7 +98,7 @@ ALTER TABLE public.posts OWNER TO postgres;
-- --
CREATE TABLE tags ( CREATE TABLE tags (
id integer NOT NULL, id serial NOT NULL,
name character varying(255) NOT NULL name character varying(255) NOT NULL
); );
@ -99,7 +110,7 @@ ALTER TABLE public.tags OWNER TO postgres;
-- --
CREATE TABLE users ( CREATE TABLE users (
id integer NOT NULL, id serial NOT NULL,
username character varying(255) NOT NULL, username character varying(255) NOT NULL,
password character varying(255) NOT NULL password character varying(255) NOT NULL
); );
@ -111,75 +122,53 @@ ALTER TABLE public.users OWNER TO postgres;
-- Data for Name: categories; Type: TABLE DATA; Schema: public; Owner: postgres -- Data for Name: categories; Type: TABLE DATA; Schema: public; Owner: postgres
-- --
COPY categories (id, name, icon) FROM stdin; INSERT INTO "categories" ("name", "icon") VALUES
1 anouncement \N ('anouncement', NULL),
2 article \N ('article', NULL);
\.
-- --
-- Data for Name: comments; Type: TABLE DATA; Schema: public; Owner: postgres -- Data for Name: comments; Type: TABLE DATA; Schema: public; Owner: postgres
-- --
COPY comments (id, post_id, message) FROM stdin; INSERT INTO "comments" ("post_id", "message") VALUES
1 1 great (1, 'great'),
2 1 fantastic (1, 'fantastic'),
3 2 thank you (2, 'thank you'),
4 2 awesome (2, 'awesome');
\.
-- --
-- Data for Name: post_tags; Type: TABLE DATA; Schema: public; Owner: postgres -- Data for Name: post_tags; Type: TABLE DATA; Schema: public; Owner: postgres
-- --
COPY post_tags (id, post_id, tag_id) FROM stdin; INSERT INTO "post_tags" ("post_id", "tag_id") VALUES
1 1 1 (1, 1),
2 1 2 (1, 2),
3 2 1 (2, 1),
4 2 2 (2, 2);
\.
-- --
-- Data for Name: posts; Type: TABLE DATA; Schema: public; Owner: postgres -- Data for Name: posts; Type: TABLE DATA; Schema: public; Owner: postgres
-- --
COPY posts (id, user_id, category_id, content) FROM stdin; INSERT INTO "posts" ("user_id", "category_id", "content") VALUES
1 1 1 blog started (1, 1, 'blog started'),
2 1 2 € Hello world, ???????? ?????, ????? (1, 2, 'It works!');
5 1 1 #1
6 1 1 #2
7 1 1 #3
8 1 1 #4
9 1 1 #5
10 1 1 #6
11 1 1 #7
12 1 1 #8
13 1 1 #9
14 1 1 #10
\.
-- --
-- Data for Name: tags; Type: TABLE DATA; Schema: public; Owner: postgres -- Data for Name: tags; Type: TABLE DATA; Schema: public; Owner: postgres
-- --
COPY tags (id, name) FROM stdin; INSERT INTO "tags" ("name") VALUES
1 funny ('funny'),
2 important ('important');
\.
-- --
-- Data for Name: users; Type: TABLE DATA; Schema: public; Owner: postgres -- Data for Name: users; Type: TABLE DATA; Schema: public; Owner: postgres
-- --
COPY users (id, username, password) FROM stdin; INSERT INTO "users" ("username", "password") VALUES
1 user1 pass1 ('user1', 'pass1'),
2 user2 pass2 ('user2', 'pass2');
\.
-- --
-- Name: categories_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- Name: categories_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace:

View file

@ -131,6 +131,7 @@ class MySQL_CRUD_API_Test extends PHPUnit_Framework_TestCase
die("Connect failed: ".print_r( sqlsrv_errors(), true)); die("Connect failed: ".print_r( sqlsrv_errors(), true));
} }
$queries = preg_split('/\n\s*GO\s*\n/', file_get_contents($fixture)); $queries = preg_split('/\n\s*GO\s*\n/', file_get_contents($fixture));
array_pop($queries);
foreach ($queries as $i=>$query) { foreach ($queries as $i=>$query) {
if (!sqlsrv_query($conn, $query)) { if (!sqlsrv_query($conn, $query)) {
$i++; $i++;
@ -139,6 +140,30 @@ class MySQL_CRUD_API_Test extends PHPUnit_Framework_TestCase
} }
sqlsrv_close($conn); sqlsrv_close($conn);
} elseif ($dbengine == 'pgsql') {
$e = function ($v) { return str_replace(array('\'','\\'),array('\\\'','\\\\'),$v); };
$hostname = $e($hostname);
$port = 5432;
$database = $database;
$username = $e($username);
$password = $e($password);
$charset = 'UTF8';
$conn_string = "host='$hostname' port=$port dbname='$database' user='$username' password='$password' options='--client_encoding=$charset'";
$db = pg_connect($conn_string);
if (!$db) {
die("Connect failed: ".print_r( sqlsrv_errors(), true));
}
$queries = preg_split('/;\s*\n/', file_get_contents($fixture));
array_pop($queries);
foreach ($queries as $i=>$query) {
if (!pg_query($db, $query.';')) {
$i++;
die("Loading '$fixture' failed on statemement #$i with error:\n".print_r( pg_last_error($db), true)."\n");
}
}
pg_close($db);
} }
} }
@ -314,11 +339,11 @@ class MySQL_CRUD_API_Test extends PHPUnit_Framework_TestCase
$test->expect('[15,16]'); $test->expect('[15,16]');
} }
public function testAddPostsFailure() public function testAddPostFailure()
{ {
$test = new API($this); $test = new API($this);
$test->post('/posts','[{"user_id":"a","category_id":"1","content":"tests"},{"user_id":"1","category_id":"1","content":"tests"}]'); $test->post('/posts','{"user_id":"a","category_id":"1","content":"tests"}');
$test->expect('[null,18]'); $test->expect('null');
} }
public function testOptionsRequest() public function testOptionsRequest()