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 /doc | |
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 'doc')
-rw-r--r-- | doc/developers.bb | 3 | ||||
-rw-r--r-- | doc/sql_conventions.bb | 87 |
2 files changed, 90 insertions, 0 deletions
diff --git a/doc/developers.bb b/doc/developers.bb index 18e39c4ea..5365fd77a 100644 --- a/doc/developers.bb +++ b/doc/developers.bb @@ -64,4 +64,7 @@ In the interests of consistency we adopt the following code styling. We may acce [li] Generally speaking, opening braces go on the same line as the thing which opens the brace. They are the last character on the line. Closing braces are on a line by themselves. [/li]
+[b]See Also[/b]
+[zrl=[baseurl]/help/sql_conventions]SQL Conventions[/zrl]
+
#include doc/macros/main_footer.bb;
diff --git a/doc/sql_conventions.bb b/doc/sql_conventions.bb new file mode 100644 index 000000000..88539ae19 --- /dev/null +++ b/doc/sql_conventions.bb @@ -0,0 +1,87 @@ +[h1]SQL Conventions[/h1] +[b]Intro[/b] +The following common SQL conventions appear throughout the code in many places. We use a simple DBA (DataBase Abstraction layer) to handle differences between databases. Please be sure to use only standards-compliant SQL. + +[b]Rule One[/b] +Worth Repeating: Don't use non-standard SQL. This goes for addons as well. If you do use non-standard SQL, and the dba funcs are insufficient, do a if()/switch() or similar for all currently supported databases. Currently nothing red# does requires non-standard SQL. + +[b]Using a format string[/b] +[li]Uses sprintf() +To be written +[code]// Example +$r = q("SELECT * FROM profile WHERE uid = %d", + local_user() +); +[/code][/li] + +[b]Checking bit flags in a where clause[/b] +[li]You must explicitly convert integers to booleans. The easiest way to do this is to compare to 0. +[code]// Example +$r = q("SELECT abook_id, abook_flags, abook_my_perms, abook_their_perms, xchan_hash, xchan_photo_m, xchan_name, xchan_url from abook left join xchan on abook_xchan = xchan_hash where abook_channel = %d and not (abook_flags & %d)>0 ", + intval($uid), + intval(ABOOK_FLAG_SELF) +); +[/code] +[/li] +[li]Turning off a flag +[code]$y = q("update xchan set xchan_flags = (xchan_flags & ~%d) where (xchan_flags & %d)>0 and xchan_hash = '%s'", + intval(XCHAN_FLAGS_ORPHAN), + intval(XCHAN_FLAGS_ORPHAN), + dbesc($rr['hubloc_hash']) +);[/code] +[/li] +[li]Turning on a flag +[code]$y = q("update xchan set xchan_flags = (xchan_flags | %d) where xchan_hash = '%s'", + intval(XCHAN_FLAGS_ORPHAN), + dbesc($rr['hubloc_hash']) +);[/code] +[/li] + +[b]Using relative times (INTERVALs)[/b] +[li]Sometimes you want to compare something, like less than x days old. +[code]// Example +$r = q("SELECT * FROM abook left join xchan on abook_xchan = xchan_hash + WHERE abook_dob > %s + interval %s and abook_dob < %s + interval %s", + db_utcnow(), db_quoteinterval('7 day'), + db_utcnow(), db_quoteinterval('14 day') +);[/code] +[/li] +[b]Paged results[/b] +[li]To be written +[code]// Example +$r = q("SELECT * FROM mail WHERE uid=%d AND $sql_extra ORDER BY created DESC LIMIT %d OFFSET %d", + intval(api_user()), + intval($count), intval($start) +);[/code][/li] + +[b]NULL dates[/b] +[li]To be written +[code]Example[/code][/li] + +[b]Storing binary data[/b] +[li]To be written +[code]// Example +$x = q("update photo set data = '%s', height = %d, width = %d where resource_id = '%s' and uid = %d and scale = 0", + dbescbin($ph->imageString()), + intval($height), + intval($width), + dbesc($resource_id), + intval($page_owner_uid) +);[/code][/li] + +[b]Current timestamp[/b] +[li][code]// Example +$randfunc = db_getfunc('rand'); +$r = q("select xchan_url from xchan left join hubloc on hubloc_hash = xchan_hash where hubloc_connected > %s - interval %s order by $randfunc limit 1", + db_utcnow(), db_quoteinterval('30 day') +);[/code][/li] + +[b]SQL Function and Operator Abstraction[/b] +[li]Sometimes the same function or operator has a different name/symbol in each database. You use db_getfunc('funcname') to look them up. The string is [i]not[/i] case-sensitive; do [i]not[/i] include parens. +[code]// Example +$randfunc = db_getfunc('rand'); +$r = q("select xchan_url from xchan left join hubloc on hubloc_hash = xchan_hash where hubloc_connected > %s - interval %s order by $randfunc limit 1", + db_utcnow(), db_quoteinterval('30 day') +);[/code][/li] + +#include doc/macros/main_footer.bb;
\ No newline at end of file |