This discussion is archived
6 Replies Latest reply: Dec 13, 2012 5:13 AM by Purvesh K RSS

substitution vs bind variable

546626 Newbie
Currently Being Moderated
Hi,

Can you please give me the differences between substitution vs bind variables? I have done many searches and I am lost. Any examples would be great.

Thanks.

-U
  • 1. Re: substitution vs bind variable
    AlbertoFaenza Expert
    Currently Being Moderated
    Have you tried to google it?

    Here you have all that you need and also examples.

    Regards.
    Al
  • 2. Re: substitution vs bind variable
    546626 Newbie
    Currently Being Moderated
    I did study the site before. I am still confused.

    I was looking for a better definition of each variable.

    Thanks.
  • 3. Re: substitution vs bind variable
    6363 Guru
    Currently Being Moderated
    user543623 wrote:
    I am still confused.
    What part of it did you not understand.
    I was looking for a better definition of each variable.
    Until you describe what is wrong with the explanation already provided,no one will be able to come up with an explanation that is better than it.

    When I read it seemed very well explained and most people would have a very difficult time coming up with a clearer description.
  • 4. Re: substitution vs bind variable
    Peter Gjelstrup Guru
    Currently Being Moderated
    user543623 wrote:
    I did study the site before. I am still confused.

    I was looking for a better definition of each variable.
    The ultimate resource (sub_var)

    http://www.oracle.com/technetwork/testcontent/sub-var-087723.html

    Edit:
    I like formatting better in this blog post of Christopher Jones' (author)
    https://blogs.oracle.com/opal/entry/sqlplus_101_substitution_varia

    Regards
    Peter

    Edited by: Peter on Dec 12, 2012 3:03 PM
  • 5. Re: substitution vs bind variable
    BluShadow Guru Moderator
    Currently Being Moderated
    Perhaps what is needed is a simple example of both.

    h2. Substitution Variables

    The clue here is in the name... "substitution". It relates to values being substituted into the code before it is submitted to the database. These substitutions are carried out by the interface being used. In this example we're going to use SQL*Plus as our interface...


    So let's take a bit of code with substitution variables:
    SQL> ed
    Wrote file afiedt.buf
    
      1  create or replace function myfn return varchar2 is
      2    v_dname varchar2(20);
      3  begin
      4    select dname
      5    into   v_dname
      6    from   dept
      7    where  deptno = &p_deptno;
      8    return v_dname;
      9* end;
    Now when this code is submitted...
    SQL> /
    SQL*Plus, parses the code itself, and sees the "&" indicating a substitution variable.
    SQL*Plus, then prompts for a value for that variable, which we enter...
    Enter value for p_deptno: 20
    old   7:   where  deptno = &p_deptno;
    new   7:   where  deptno = 20;
    ... and it reports back that it has substitution the &p_deptno variable for the value 20, actually shoing us the whole line of code with it's value.

    This code is then submitted to the database. So if we look at what the code is, now created on the database we see...
    SQL> select dbms_metadata.get_ddl('FUNCTION', 'MYFN', USER) from dual;
    
    DBMS_METADATA.GET_DDL('FUNCTION','MYFN',USER)
    --------------------------------------------------------------------------------
    
    CREATE OR REPLACE FUNCTION "SCOTT"."MYFN" return varchar2 is
      v_dname varchar2(20);
    begin
      select dname
      into   v_dname
      from   dept
      where  deptno = 20;
      return v_dname;
    end;
    The database itself knows nothing about any substitution variable... it just has some fixed code with the value we supplied, that SQL*Plus substituted when we compiled it.

    The only way we can change that value is by recompiling the code again, and substituting a new value for it.

    Also, with substitution variables we don't necessarily have to use them just for 'values' (though that it typically what they're used for)... we can use them to substitute any part of the code/text that we are supplying to be compiled.. e.g.
    SQL> ed
    Wrote file afiedt.buf
    
      1  create or replace function myfn(x in number, y in number) return number is
      2  begin
      3    return &what_do_you_want_to_return;
      4* end;
    SQL> /
    Enter value for what_do_you_want_to_return: y*power(x,2)
    old   3:   return &what_do_you_want_to_return;
    new   3:   return y*power(x,2);
    
    Function created.
    
    SQL> select dbms_metadata.get_ddl('FUNCTION', 'MYFN', USER) from dual;
    
    DBMS_METADATA.GET_DDL('FUNCTION','MYFN',USER)
    --------------------------------------------------------------------------------
    
    CREATE OR REPLACE FUNCTION "SCOTT"."MYFN" (x in number, y in number) return number is
    begin
      return y*power(x,2);
    end;
    It really does substitute the substitution variable, with whatever text you type.

    So, that's substitution variables. In summary they are variables that the user interface detects and prompts for text to substitute into the code before submitting it to the database.


    h2. Bind Variables

    Bind variables are a completely difference concept to substitution variables.
    Bind variables typically relate to SQL queries, and are a placeholder for values within the query. Unlike substitution variables, these are not prompted for when you come to compile the code.

    Now there are various ways of supplying bind variables, and I'll use a couple of examples, but there are more (such as binding when creating queries via the DBMS_SQL package etc.)

    In the following exaxmple:
    SQL> ed
    Wrote file afiedt.buf
    
      1  create or replace function myfn(p_deptno in number) return varchar2 is
      2    v_dname varchar2(20);
      3    v_sql   varchar2(32767);
      4  begin
      5    v_sql := 'select dname from dept where deptno = :1';
      6    execute immediate v_sql into v_dname using p_deptno;
      7    return v_dname;
      8* end;
    SQL> /
    
    Function created.
    The ":1" is the bind variable in the query.
    If you examine queries running in the database you will typically see bind variables represented as :1, :2, :3 and so on, though it could be anything preceded by a ":" such as :A, :B, :C, :X, :FRED, :SOMETHING etc.

    When the query is passed to the SQL engine (in this case by the EXECUTE IMMEDIATE statement), the query is parsed and optimised and the best execution plan determined. It doesn't need to know what that value is yet to determine the best plan. Then when the query is actually executed, the value that has been bound in (in this case with the USING part of the execute immediate statement) is used within the execution of the query to fetch the required data.

    The advantage of using bind variables is that, if the same query is executed multiple times with different values being bound in, then the same execution plan is used because the query itself hasn't actually changed (so no hard parsing and determining the best plan has to be performed, saving time and resources).

    Another example of using bind variable is this:
    SQL> ed
    Wrote file afiedt.buf
    
      1  create or replace function myfn(p_deptno in number) return varchar2 is
      2    v_dname varchar2(20);
      3  begin
      4    select dname
      5    into   v_dname
      6    from   dept
      7    where deptno = p_deptno;
      8    return v_dname;
      9* end;
    SQL> /
    
    Function created.
    Now, this isn't immediately obvious, but what we have here is the ability of the PL langauge to seamlessly integrate SQL within it (giving us PL/SQL). It looks as though we just have an SQL statement in our code, but in reality, the PL engine parses the query and supplies the query to the SQL engine with a bind variable placeholder for where the PL variable (parameter p_deptno in this case) is within it. So the SQL engine will get a query like...
    select dname
    from   dept
    where  deptno = :1
    and then the PL engine will handle the binding of the value (p_deptno) into that query when it executes it, as well as dealing with the returning value being put INTO the PL variable v_dname. Again the SQL supplied to the SQL engine can be optimised and re-used by code because it isn't hard coded with values.

    So, here, the binding of values is implicit because the PL engine is removing the need for us to have to code them explicitly.

    The other advantage of using bind variables is that you don't have to worry about the datatypes.
    Often we see people creating code such as this (going back to a similar dynamic SQL example)...
    SQL> ed
    Wrote file afiedt.buf
    
      1  create or replace function myfn(p_hiredate in date) return number is
      2    v_empno number;
      3    v_sql   varchar2(32767);
      4  begin
      5    v_sql := 'select empno from emp where hiredate = to_date('||to_char(p_hiredate,'DD/MM/YYYY')||',''DD/MM/YYYY'')';
      6    execute immediate v_sql into v_empno;
      7    return v_empno;
      8* end;
    SQL> /
    
    Function created.
    ... where the developer is trying to concatenate in a date or varchar variable with the appropriate single quotes and formatting required to make the SQL make sense. Not only does that prevent the SQL explain plan from being re-used with different values, but it makes the code hard to maintain and get right in the first place (as well as leaving things open to SQL injection)

    But, with bind variable, that's not necessary... simply doing...
    SQL> ed
    Wrote file afiedt.buf
    
      1  create or replace function myfn(p_hiredate in date) return number is
      2    v_empno number;
      3    v_sql   varchar2(32767);
      4  begin
      5    v_sql := 'select empno from emp where hiredate = :1';
      6    execute immediate v_sql into v_empno using p_hiredate;
      7    return v_empno;
      8* end;
    SQL> /
    
    Function created.
    ... is all that is needed.
    The SQL engine knows that it is expecting a DATE datatype for the value because of what it's being compared against, and the USING statement is supplying a value of DATE datatype. No messy need to play with date formats or quotes etc. it just simply works. (and the same with other datatypes).

    So, that's bind variables. In summary they are placeholders in queries that allow SQL queries to be soft parsed rather than hard parsed when the query is re-used, help prevent SQL injection, and allow for the values to be supplied easily and seamlessly by the issuing code.
  • 6. Re: substitution vs bind variable
    Purvesh K Guru
    Currently Being Moderated
    This is byfar the most brilliant description of Substitution variable and Bind Variables. :)

    My suggestion would be to link in the FAQ's for people to access it easily.