From 1a5a5c7edb8697c93f8bababbafa80245378dd7e Mon Sep 17 00:00:00 2001 From: Habeas Codice Date: Thu, 13 Nov 2014 12:21:58 -0800 Subject: 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) --- include/poller.php | 51 +++++++++++++++++++++++++++++++-------------------- 1 file changed, 31 insertions(+), 20 deletions(-) (limited to 'include/poller.php') diff --git a/include/poller.php b/include/poller.php index f11618d37..8e52d6e05 100644 --- a/include/poller.php +++ b/include/poller.php @@ -44,15 +44,17 @@ function poller_run($argv, $argc){ // expire any expired mail - q("delete from mail where expires != '%s' and expires < UTC_TIMESTAMP() ", - dbesc(NULL_DATE) + q("delete from mail where expires != '%s' and expires < %s ", + dbesc(NULL_DATE), + db_utcnow() ); // expire any expired items - $r = q("select id from item where expires != '%s' and expires < UTC_TIMESTAMP() - and not ( item_restrict & %d ) ", + $r = q("select id from item where expires != '%s' and expires < %s + and not ( item_restrict & %d )>0 ", dbesc(NULL_DATE), + db_utcnow(), intval(ITEM_DELETED) ); if($r) { @@ -66,7 +68,9 @@ function poller_run($argv, $argc){ // channels and sites that quietly vanished and prevent the directory from accumulating stale // or dead entries. - $r = q("select channel_id from channel where channel_dirdate < UTC_TIMESTAMP() - INTERVAL 30 DAY"); + $r = q("select channel_id from channel where channel_dirdate < %s - INTERVAL %s", + db_utcnow(), db_quoteinterval('30 DAY') + ); if($r) { foreach($r as $rr) { proc_run('php','include/directory.php',$rr['channel_id'],'force'); @@ -78,12 +82,13 @@ function poller_run($argv, $argc){ // publish any applicable items that were set to be published in the future // (time travel posts) - $r = q("select id from item where ( item_restrict & %d ) and created <= UTC_TIMESTAMP() ", - intval(ITEM_DELAYED_PUBLISH) + $r = q("select id from item where ( item_restrict & %d )>0 and created <= %s ", + intval(ITEM_DELAYED_PUBLISH), + db_utcnow() ); if($r) { foreach($r as $rr) { - $x = q("update item set item_restrict = ( item_restrict ^ %d ) where id = %d limit 1", + $x = q("update item set item_restrict = ( item_restrict & ~%d ) where id = %d", intval(ITEM_DELAYED_PUBLISH), intval($rr['id']) ); @@ -167,7 +172,9 @@ function poller_run($argv, $argc){ // expire any read notifications over a month old - q("delete from notify where seen = 1 and date < UTC_TIMESTAMP() - INTERVAL 30 DAY"); + q("delete from notify where seen = 1 and date < %s - INTERVAL %s", + db_utcnow(), db_quoteinterval('30 DAY') + ); // expire any expired accounts downgrade_accounts(); @@ -199,13 +206,15 @@ function poller_run($argv, $argc){ // This should be rare $r = q("select xchan_photo_l, xchan_hash from xchan where xchan_photo_l != '' and xchan_photo_m = '' - and xchan_photo_date < UTC_TIMESTAMP() - INTERVAL 1 DAY"); + and xchan_photo_date < %s - INTERVAL %s", + db_utcnow(), db_quoteinterval('1 DAY') + ); if($r) { require_once('include/photo/photo_driver.php'); foreach($r as $rr) { $photos = import_profile_photo($rr['xchan_photo_l'],$rr['xchan_hash']); $x = q("update xchan set xchan_photo_l = '%s', xchan_photo_m = '%s', xchan_photo_s = '%s', xchan_photo_mimetype = '%s' - where xchan_hash = '%s' limit 1", + where xchan_hash = '%s'", dbesc($photos[0]), dbesc($photos[1]), dbesc($photos[2]), @@ -258,16 +267,17 @@ function poller_run($argv, $argc){ // Only poll from those with suitable relationships $abandon_sql = (($abandon_days) - ? sprintf(" AND account_lastlog > UTC_TIMESTAMP() - INTERVAL %d DAY ", intval($abandon_days)) + ? sprintf(" AND account_lastlog > %s - INTERVAL %s ", db_utcnow(), db_quoteinterval(intval($abandon_days).' DAY')) : '' ); - + $randfunc = (ACTIVE_DBTYPE == DBTYPE_POSTGRES) ? 'RANDOM()' : 'RAND()'; + $contacts = q("SELECT abook_id, abook_flags, abook_updated, abook_connected, abook_closeness, abook_xchan, abook_channel - FROM abook LEFT JOIN account on abook_account = account_id where 1 + FROM abook LEFT JOIN account on abook_account = account_id $sql_extra - AND (( abook_flags & %d ) OR ( abook_flags = %d )) - AND (( account_flags = %d ) OR ( account_flags = %d )) $abandon_sql ORDER BY RAND()", + AND (( abook_flags & %d )>0 OR ( abook_flags = %d )) + AND (( account_flags = %d ) OR ( account_flags = %d )) $abandon_sql ORDER BY $randfunc", intval(ABOOK_FLAG_HIDDEN|ABOOK_FLAG_PENDING|ABOOK_FLAG_UNCONNECTED|ABOOK_FLAG_FEED), intval(0), intval(ACCOUNT_OK), @@ -308,7 +318,7 @@ function poller_run($argv, $argc){ // if we've never connected with them, start the mark for death countdown from now if($c == NULL_DATE) { - $r = q("update abook set abook_connected = '%s' where abook_id = %d limit 1", + $r = q("update abook set abook_connected = '%s' where abook_id = %d", dbesc(datetime_convert()), intval($contact['abook_id']) ); @@ -323,7 +333,7 @@ function poller_run($argv, $argc){ dbesc($contact['abook_xchan']) ); if($n && $n[0]['xchan_network'] == 'zot') { - $r = q("update abook set abook_flags = (abook_flags | %d) where abook_id = %d limit 1", + $r = q("update abook set abook_flags = (abook_flags | %d) where abook_id = %d", intval(ABOOK_FLAG_ARCHIVED), intval($contact['abook_id']) ); @@ -365,9 +375,10 @@ function poller_run($argv, $argc){ } if($dirmode == DIRECTORY_MODE_SECONDARY || $dirmode == DIRECTORY_MODE_PRIMARY) { - $r = q("select distinct ud_addr, updates.* from updates where not ( ud_flags & %d ) and ud_addr != '' and ( ud_last = '%s' OR ud_last > UTC_TIMESTAMP() - INTERVAL 7 DAY ) group by ud_addr ", + $r = q("select distinct ud_addr, updates.* from updates where not ( ud_flags & %d )>0 and ud_addr != '' and ( ud_last = '%s' OR ud_last > %s - INTERVAL %s ) group by ud_addr ", intval(UPDATE_FLAGS_UPDATED), - dbesc(NULL_DATE) + dbesc(NULL_DATE), + db_utcnow(), db_quoteinterval('7 DAY') ); if($r) { foreach($r as $rr) { -- cgit v1.2.3