unofficial mirror of guile-user@gnu.org 
 help / color / mirror / Atom feed
* SQL injection with guile-pg
@ 2005-01-06 16:52 Greg Troxel
  2005-02-11 10:45 ` Thien-Thi Nguyen
  0 siblings, 1 reply; 5+ messages in thread
From: Greg Troxel @ 2005-01-06 16:52 UTC (permalink / raw)


I'm writing some code with guile-pg, and on reading:

  http://www.unixwiz.net/techtips/sql-injection.html

went to check my code.

My application sends multicast packets with key/value pairs using the
print representation of alists, basically.  On receipt of a packet from
host "foo", the strings are updated in a table with columns hostname,
key and value.
I am using the single-table abstraction for most of this, and find
that it quotes properly (using sql-quote in postgres-tables.scm) when
using type converters.

However, in order to delete the old value, and to look up values, I
used a where clause that I had constructed.  This turned out to be
vulnerable since it did not quote.

My code looked something like this

;; Make where clause for hostname and key
(define (ssp-where-body hostname key)
  (string-append "hostname = '" hostname
		  "' and key = '" key "'"))

(define (ssp-where hostname key)
  (where-clausifier (ssp-where-body hostname key)))

;; Fetch value for hostname and key.  Return #f if not in database.
;; Return 'multiple if there are multiple values (this is an error,
;; but ssp-delete still should delete them in this case.
(define-public (ssp-fetch hostname key)
  (let
      ((r
      (((ssp-manager) 'select)
       "value"
        (ssp-where hostname key))))
    (if (and (equal? 'PGRES_TUPLES_OK (pg-result-status r))
         (> (pg-ntuples r) 0))
	 (if (= 1 (pg-ntuples r))
	     (pg-getvalue r 0 0)
	         'multiple)
		 #f)))

With that, the following dropped my table:

(ssp-fetch "foobar" "test'; drop table ssp; select * from configuredlocation where hostname = 'foo")

So, I changed to


With that, inserting unreasonable strings worked fine:

guile> (ssp-update "foobar" "test'; drop table ssp; select * from configuredlocation where hostname = 'foo" "bar")
#<PG-RESULT:60:PGRES_COMMAND_OK:0:0>


psql# select * from ssp;
 hostname |                                      key                                      | value 
----------+-------------------------------------------------------------------------------+-------
 foobar   | test'; drop table ssp; select * from configuredlocation where hostname = 'foo | bar
(1 row)

guile> (ssp-fetch "foobar" "test'; drop table ssp; select * from configuredlocation where hostname = 'foo")
"bar"


I don't mean to criticize guile-pg; the error above was mine in using
input data unquoted in a query, and is a standard SQL newbie error.

It would be nice, though, to have sql-quote as a user-accessible procedure.

It would be further cool to do two things:

  use bound parameters, so that the strings aren't part of the sql
  command, but are passed as data


  have some support to make a sql command fragment with safe/quoted type conversion, perhaps something like
  (sql-prep "select foo from bar where a = " (list 'text s) ";")
  where s is a string.

Thanks to ttn for maintaining guile-pg; despite my wishes for more I'm
glad to be doing things in guile rather than perl.



_______________________________________________
Guile-user mailing list
Guile-user@gnu.org
http://lists.gnu.org/mailman/listinfo/guile-user


^ permalink raw reply	[flat|nested] 5+ messages in thread

* Re: SQL injection with guile-pg
  2005-01-06 16:52 SQL injection with guile-pg Greg Troxel
@ 2005-02-11 10:45 ` Thien-Thi Nguyen
  2005-02-14 13:23   ` Greg Troxel
  0 siblings, 1 reply; 5+ messages in thread
From: Thien-Thi Nguyen @ 2005-02-11 10:45 UTC (permalink / raw)
  Cc: guile-user

   From: Greg Troxel <gdt@ir.bbn.com>
   Date: Thu, 06 Jan 2005 11:52:29 -0500

   It would be nice, though, to have sql-quote as a user-accessible
   procedure.

in cvs there is a new module (database postgres-qcons) for "query
construction" which exposes `sql-quote'.

at the moment, i'm mulling over what else to add to that module.

ideally we would follow the design of SchemeQL by Francisco Solsona, but
my macro-fu is not yet up the task, so for now i'm considering providing
plain procedures that address pieces of the problem, learning from those
(mis-)steps, and revisiting the all-singing all-dancing macro approach
later.

this is, btw, in contrast to the design methodology for the single-table
abstraction, which went for the throat early on and now shows scaling
problems in the type converters (explained in the info page in cvs).  i
understood that single-table abstraction is a specialized application of
schema (in the database sense) mirroring (in the LAML sense), but did
not understand how to avoid the need for backtracking at that time...

     use bound parameters, so that the strings aren't part of the sql
     command, but are passed as data

could you show an example of this?

     have some support to make a sql command fragment with safe/quoted
     type conversion, perhaps something like

     (sql-prep "select foo from bar where a = " (list 'text s) ";")

     where s is a string.

see `compile-outspec' (available since Guile-PG 0.17, 2004-02-02) for
foo-position munging.  parts of its analysis can be (probably will be)
generalized for where-clause use, in (database postgres-qcons).

thi


_______________________________________________
Guile-user mailing list
Guile-user@gnu.org
http://lists.gnu.org/mailman/listinfo/guile-user


^ permalink raw reply	[flat|nested] 5+ messages in thread

* Re: SQL injection with guile-pg
  2005-02-11 10:45 ` Thien-Thi Nguyen
@ 2005-02-14 13:23   ` Greg Troxel
  2005-02-14 21:17     ` Thien-Thi Nguyen
  0 siblings, 1 reply; 5+ messages in thread
From: Greg Troxel @ 2005-02-14 13:23 UTC (permalink / raw)
  Cc: guile-user

For a bound parameter example, look at the 'stage 2' code fragment
here:

  http://www.saturn5.com/~jwb/dbi-performance.html 

Basically, you have a query string with a variable name in it, and then
execute a statement that binds a value to that name.  People do this
partly for efficiency, but it also prevents the sql parser from reading
the data.


-- 
        Greg Troxel <gdt@ir.bbn.com>


_______________________________________________
Guile-user mailing list
Guile-user@gnu.org
http://lists.gnu.org/mailman/listinfo/guile-user


^ permalink raw reply	[flat|nested] 5+ messages in thread

* Re: SQL injection with guile-pg
  2005-02-14 13:23   ` Greg Troxel
@ 2005-02-14 21:17     ` Thien-Thi Nguyen
  2005-02-15 14:41       ` Greg Troxel
  0 siblings, 1 reply; 5+ messages in thread
From: Thien-Thi Nguyen @ 2005-02-14 21:17 UTC (permalink / raw)
  Cc: guile-user

   From: Greg Troxel <gdt@ir.bbn.com>
   Date: 14 Feb 2005 08:23:08 -0500

   http://www.saturn5.com/~jwb/dbi-performance.html 

thanks for the link.  perhaps Guile-PG can provide some convenience
procedures for the PREPARE and EXECUTE statements.  is that what you
had in mind?  any templating/caching done on the client side is IMHO
not worth the effort next to the performance gains possible w/ server
mechanisms.  however, raising the abstraction makes it worthwhile.

thi


_______________________________________________
Guile-user mailing list
Guile-user@gnu.org
http://lists.gnu.org/mailman/listinfo/guile-user


^ permalink raw reply	[flat|nested] 5+ messages in thread

* Re: SQL injection with guile-pg
  2005-02-14 21:17     ` Thien-Thi Nguyen
@ 2005-02-15 14:41       ` Greg Troxel
  0 siblings, 0 replies; 5+ messages in thread
From: Greg Troxel @ 2005-02-15 14:41 UTC (permalink / raw)
  Cc: guile-user

I wasn't suggesing client-side caching; I agree that it seems not
worthwhile, at least now.

Bound parameters have two benefits, and a third in the guile-pg world:

  security (avoiding SQL injection)

  enabling server-side query caching since the variables are not part
  of the query proper any more

  [guile-pg] a path to automatic type conversion from Scheme->SQL, and
  easier explicit type conversion

In PG 7.4.6 docs, see section 27.2, PQexecParams.
Just adding a wrapper for that would be a big step forward.

Then I guess PQexecPrepared would be next; it's almost like
PGexecParams.  While one is supposed to just do a PQexec of a SQL
PREPARE statement, it might be nice to have a pq-prepare Scheme
procedure that returns the prepared name in a boxed type and make
PQexecPrepared require that, adding a bit more type safety than pg/SQL
has to start with.

The docs talk about the parameter types being known after the
statement is prepared.  If these can be extracted and put in the boxed
type with the query name, then the list of scheme params could be
converted to them via the registered type converters, and that would
be a very nice interface.

-- 
        Greg Troxel <gdt@ir.bbn.com>


_______________________________________________
Guile-user mailing list
Guile-user@gnu.org
http://lists.gnu.org/mailman/listinfo/guile-user


^ permalink raw reply	[flat|nested] 5+ messages in thread

end of thread, other threads:[~2005-02-15 14:41 UTC | newest]

Thread overview: 5+ messages (download: mbox.gz follow: Atom feed
-- links below jump to the message on this page --
2005-01-06 16:52 SQL injection with guile-pg Greg Troxel
2005-02-11 10:45 ` Thien-Thi Nguyen
2005-02-14 13:23   ` Greg Troxel
2005-02-14 21:17     ` Thien-Thi Nguyen
2005-02-15 14:41       ` Greg Troxel

This is a public inbox, see mirroring instructions
for how to clone and mirror all data and code used for this inbox;
as well as URLs for read-only IMAP folder(s) and NNTP newsgroup(s).