diff options
author | Habeas Codice <habeascodice@federated.social> | 2014-11-13 12:21:58 -0800 |
---|---|---|
committer | Habeas Codice <habeascodice@federated.social> | 2014-11-13 12:21:58 -0800 |
commit | 1a5a5c7edb8697c93f8bababbafa80245378dd7e (patch) | |
tree | b3d3b5ff30ecce1316ad0386d0e89fe18a867b4f /include/socgraph.php | |
parent | 31376de0665091f2dba04755562ccd238d57a13c (diff) | |
download | volse-hubzilla-1a5a5c7edb8697c93f8bababbafa80245378dd7e.tar.gz volse-hubzilla-1a5a5c7edb8697c93f8bababbafa80245378dd7e.tar.bz2 volse-hubzilla-1a5a5c7edb8697c93f8bababbafa80245378dd7e.zip |
PostgreSQL support initial commit
There were 11 main types of changes:
- UPDATE's and DELETE's sometimes had LIMIT 1 at the end of them. This is not only non-compliant but
it would certainly not do what whoever wrote it thought it would. It is likely this mistake was just
copied from Friendica. All of these instances, the LIMIT 1 was simply removed.
- Bitwise operations (and even some non-zero int checks) erroneously rely on MySQL implicit
integer-boolean conversion in the WHERE clauses. This is non-compliant (and bad programming practice
to boot). Proper explicit boolean conversions were added. New queries should use proper conventions.
- MySQL has a different operator for bitwise XOR than postgres. Rather than add yet another dba_
func, I converted them to "& ~" ("AND NOT") when turning off, and "|" ("OR") when turning on. There
were no true toggles (XOR). New queries should refrain from using XOR when not necessary.
- There are several fields which the schema has marked as NOT NULL, but the inserts don't specify
them. The reason this works is because mysql totally ignores the constraint and adds an empty text
default automatically. Again, non-compliant, obviously. In these cases a default of empty text was
added.
- Several statements rely on a non-standard MySQL feature
(http://dev.mysql.com/doc/refman/5.5/en/group-by-handling.html). These queries can all be rewritten
to be standards compliant. Interestingly enough, the newly rewritten standards compliant queries run
a zillion times faster, even on MySQL.
- A couple of function/operator name translations were needed (RAND/RANDOM, GROUP_CONCAT/STRING_AGG,
UTC_NOW, REGEXP/~, ^/#) -- assist functions added in the dba_
- INTERVALs: postgres requires quotes around the value, mysql requires that there are not quotes
around the value -- assist functions added in the dba_
- NULL_DATE's -- Postgres does not allow the invalid date '0000-00-00 00:00:00' (there is no such
thing as year 0 or month 0 or day 0). We use '0001-01-01 00:00:00' for postgres. Conversions are
handled in Zot/item packets automagically by quoting all dates with dbescdate().
- char(##) specifications in the schema creates fields with blank spaces that aren't trimmed in the
code. MySQL apparently treats char(##) as varchar(##), again, non-compliant. Since postgres works
better with text fields anyway, this ball of bugs was simply side-stepped by using 'text' datatype
for all text fields in the postgres schema. varchar was used in a couple of places where it actually
seemed appropriate (size constraint), but without rigorously vetting that all of the PHP code
actually validates data, new bugs might come out from under the rug.
- postgres doesn't store nul bytes and a few other non-printables in text fields, even when quoted.
bytea fields were used when storing binary data (photo.data, attach.data). A new dbescbin() function
was added to handle this transparently.
- postgres does not support LIMIT #,# syntax. All databases support LIMIT # OFFSET # syntax.
Statements were updated to be standard.
These changes require corresponding changes in the coding standards. Please review those before
adding any code going forward.
Still on my TODO list:
- remove quotes from non-reserved identifiers and make reserved identifiers use dba func for quoting
- Rewrite search queries for better results (both MySQL and Postgres)
Diffstat (limited to 'include/socgraph.php')
-rw-r--r-- | include/socgraph.php | 57 |
1 files changed, 31 insertions, 26 deletions
diff --git a/include/socgraph.php b/include/socgraph.php index 504a6b2c0..740886b1c 100644 --- a/include/socgraph.php +++ b/include/socgraph.php @@ -77,7 +77,7 @@ function poco_load($xchan = '',$url = null) { dbesc($xchan) ); if($r) { - q("update xchat set xchat_edited = '%s' where xchat_id = %d limit 1", + q("update xchat set xchat_edited = '%s' where xchat_id = %d", dbesc(datetime_convert()), intval($r[0]['xchat_id']) ); @@ -93,7 +93,8 @@ function poco_load($xchan = '',$url = null) { } } } - q("delete from xchat where xchat_edited < UTC_TIMESTAMP() - INTERVAL 7 DAY and xchat_xchan = '%s' ", + q("delete from xchat where xchat_edited < %s - INTERVAL %s and xchat_xchan = '%s' ", + db_utcnow(), db_quoteinterval('7 DAY'), dbesc($xchan) ); } @@ -195,7 +196,7 @@ function poco_load($xchan = '',$url = null) { ); } else { - q("update xlink set xlink_updated = '%s', xlink_rating = %d where xlink_id = %d limit 1", + q("update xlink set xlink_updated = '%s', xlink_rating = %d where xlink_id = %d", dbesc(datetime_convert()), intval($rating), intval($r[0]['xlink_id']) @@ -204,8 +205,9 @@ function poco_load($xchan = '',$url = null) { } logger("poco_load: loaded $total entries",LOGGER_DEBUG); - q("delete from xlink where xlink_xchan = '%s' and xlink_updated < UTC_TIMESTAMP() - INTERVAL 2 DAY", - dbesc($xchan) + q("delete from xlink where xlink_xchan = '%s' and xlink_updated < %s - INTERVAL %s", + dbesc($xchan), + db_utcnow(), db_quoteinterval('2 DAY') ); } @@ -227,18 +229,19 @@ function count_common_friends($uid,$xchan) { function common_friends($uid,$xchan,$start = 0,$limit=100000000,$shuffle = false) { + $rand = db_getfunc('rand'); if($shuffle) - $sql_extra = " order by rand() "; + $sql_extra = " order by $rand "; else $sql_extra = " order by xchan_name asc "; $r = q("SELECT * from xchan left join xlink on xlink_link = xchan_hash where xlink_xchan = '%s' and xlink_link in - (select abook_xchan from abook where abook_xchan != '%s' and abook_channel = %d and abook_flags = 0 ) $sql_extra limit %d, %d", + (select abook_xchan from abook where abook_xchan != '%s' and abook_channel = %d and abook_flags = 0 ) $sql_extra limit %d offset %d", dbesc($xchan), dbesc($xchan), intval($uid), - intval($start), - intval($limit) + intval($limit), + intval($start) ); return $r; @@ -273,11 +276,11 @@ function common_friends_zcid($uid,$zcid,$start = 0, $limit = 9999,$shuffle = fal FROM `glink` left join `gcontact` on `glink`.`gcid` = `gcontact`.`id` where `glink`.`zcid` = %d and `gcontact`.`nurl` in (select nurl from contact where uid = %d and self = 0 and blocked = 0 and hidden = 0 ) - $sql_extra limit %d, %d", + $sql_extra limit %d offset %d", intval($zcid), intval($uid), - intval($start), - intval($limit) + intval($limit), + intval($start) ); return $r; @@ -306,11 +309,11 @@ function all_friends($uid,$cid,$start = 0, $limit = 80) { $r = q("SELECT `gcontact`.* FROM `glink` left join `gcontact` on `glink`.`gcid` = `gcontact`.`id` where `glink`.`cid` = %d and `glink`.`uid` = %d - order by `gcontact`.`name` asc LIMIT %d, %d ", + order by `gcontact`.`name` asc LIMIT %d OFFSET %d ", intval($cid), intval($uid), - intval($start), - intval($limit) + intval($limit), + intval($start) ); return $r; @@ -329,16 +332,16 @@ function suggestion_query($uid, $myxchan, $start = 0, $limit = 80) { and not xlink_link in ( select abook_xchan from abook where abook_channel = %d ) and not xlink_link in ( select xchan from xign where uid = %d ) and xlink_xchan != '' - and not ( xchan_flags & %d ) - and not ( xchan_flags & %d ) - group by xchan_hash order by total desc limit %d, %d ", + and not ( xchan_flags & %d )>0 + and not ( xchan_flags & %d )>0 + group by xchan_hash order by total desc limit %d offset %d ", intval($uid), intval($uid), intval($uid), intval(XCHAN_FLAGS_HIDDEN), intval(XCHAN_FLAGS_DELETED), - intval($start), - intval($limit) + intval($limit), + intval($start) ); if($r && count($r) >= ($limit -1)) @@ -349,15 +352,15 @@ function suggestion_query($uid, $myxchan, $start = 0, $limit = 80) { where xlink_xchan = '' and not xlink_link in ( select abook_xchan from abook where abook_channel = %d ) and not xlink_link in ( select xchan from xign where uid = %d ) - and not ( xchan_flags & %d ) - and not ( xchan_flags & %d ) - group by xchan_hash order by total desc limit %d, %d ", + and not ( xchan_flags & %d )>0 + and not ( xchan_flags & %d )>0 + group by xchan_hash order by total desc limit %d offset %d ", intval($uid), intval($uid), intval(XCHAN_FLAGS_HIDDEN), intval(XCHAN_FLAGS_DELETED), - intval($start), - intval($limit) + intval($limit), + intval($start) ); if(is_array($r) && is_array($r2)) @@ -394,7 +397,9 @@ function update_suggestions() { // the targets may have changed their preferences and don't want to be suggested - and they // may have simply gone away. - $r = q("delete from xlink where xlink_xchan = '' and xlink_updated < UTC_TIMESTAMP() - INTERVAL 7 DAY"); + $r = q("delete from xlink where xlink_xchan = '' and xlink_updated < %s - INTERVAL %s", + db_utcnow(), db_quoteinterval('7 DAY') + ); $j = json_decode($ret['body'],true); |