-1

Actually I am creating stored procedure with substitution, while trying to compile the procedure, I get the popup to enter the substitution values in compiling itself, Instead of getting popup while execution.

Please share me your idea to compile the procedure without asking the substitution

Littlefoot
  • 131,892
  • 15
  • 35
  • 57

2 Answers2

0

In SQL*Plus or Oracle SQL Developer, you'd SET DEFINE OFF. You tagged the question with PL/SQL Developer tag (which is a tool I don't use), but - see if this helps.

However: I'd suggest you not to do it that way. If you're creating a stored procedure, then use its parameters, don't ask for substitution variables. Something like this:

SQL> set serveroutput on
SQL> create or replace procedure p_test (par_deptno in dept.deptno%type) is
  2  begin
  3    dbms_output.put_line('Department ' || par_deptno);
  4  end;
  5  /

Procedure created.

SQL> exec p_test(10);
Department 10

PL/SQL procedure successfully completed.

You can now reuse such a procedure, passing any parameter value you want.


The way you're doing it now:

SQL> create or replace procedure p_test is
  2  begin
  3    dbms_output.put_line('Department ' || &par_deptno);
  4  end;
  5  /
Enter value for par_deptno: 25
old   3:   dbms_output.put_line('Department ' || &par_deptno);
new   3:   dbms_output.put_line('Department ' || 25);

Procedure created.

SQL> exec p_test
Department 25

PL/SQL procedure successfully completed.

SQL>

you can run the procedure many times, but it'll always display (i.e. use) the same value, throughout that session. Once you exit and log in again, procedure will always use the same value.

Littlefoot
  • 131,892
  • 15
  • 35
  • 57
0

You cannot! A substitution variable acts like a find-replace operation in the client application at the time the statement is run; the database does NOT see the substitution variable as the client application you are using will have already performed the find-replace operation. Which, for a procedure, would be at the time the CREATE PROCEDURE statement is sent from the client to the database to be compiled. It is NOT an operation that the database performs.

If you try it in a client that does not support substitution variables (or in a client that does support it after turning off substitution variables using, for example, the command SET DEFINE OFF in the client application) then you will get a compilation error. db<>fiddle

If you want to use substitution variables then use them in the anonymous block when you call the procedure.

An example procedure would take parameters and have no substitution variable:

CREATE PROCEDURE procedure_name(
  p_value IN NUMBER
)
IS
BEGIN
  -- Do something
  DBMS_OUTPUT.PUT_LINE( p_value );
END;
/

Then when you want to execute the procedure you can use a substitution variable in the calling block:

BEGIN
  procedure_name( &value );
END;
/
MT0
  • 143,790
  • 11
  • 59
  • 117
  • **Create procedure proc1(Id in number) AS BEGIN proc2('&value') end; ** Actually I try to execute proc2 inside proc1 procedure, but while compiling itself it ask for the substitution value, How do I compile without providing substitution value. @MT0 – Caroline Sep 03 '21 at 10:28
  • If you want to turn substitution variables off when compiling the procedure then https://stackoverflow.com/questions/7103715/escape-ampersand-in-pl-sql-developer/33719066 – MT0 Sep 03 '21 at 10:37