Query processor could not produce a query plan... 
Author Message
 Query processor could not produce a query plan...

Hi all,

I need to force the SQL Server to use specific index (strange thing - in QA
it uses good index, when I place it in SP, uses wrong one...). For this
reason, I used ... WITH(INDEX(...)) ... in SQL query. Again, in QA it works
fine, but when I place it in SP, I get this message:
"Query processor could not produce a query plan because of the hints defined
in this query. Resubmit the query without specifying any hints and without
using SET FORCEPLAN."  (error 8622)

I tried to put these SETs inside:
SET ANSI_NULLS ON
SET ANSI_PADDING ON
SET ANSI_WARNINGS ON
SET ARITHABORT ON
SET CONCAT_NULL_YIELDS_NULL ON
SET QUOTED_IDENTIFIER  ON
SET NUMERIC_ROUNDABORT OFF

but it doesn't help :-(((
I tried to put "with recompile" to SP - doesn't help.

I have no idea what the problem can be.
Any ideas very welcome.

Thank you,
    Petr Langer



Tue, 26 Jul 2005 04:28:19 GMT
 Query processor could not produce a query plan...

The problem with the parameters might be caused by one of the things
mentioned by Bart in the section below.  But you should remove ALL query
hints and SET's from in the stored procedure and let the optimizer do it's
thing.  Including these SET statements that you listed may force the query
to be recompiled each time its run, especially if the current connection
settings are different than those.  If you need any of these a specific way
and it isn't already defaulted that way then issue the SET statements
outside of the CREATE PROCEDURE block.

The reason for the performance difference stems from a feature called
"parameter sniffing".  Consider a stored proc defined as follows:



     GO

Keep in mind that the server has to compile a complete execution plan for
the proc before the proc begins to execute.  In 6.5, at compile time SQL

when compiling a plan.  Suppose all of the actual parameter values for

integers that were greater than 0, but suppose 40% of the [c1] values in
[table1] were, in fact, 0.  SQL would use the average density of the
column to estimate the number of rows that this predicate would return;
this would be an overestimate, and SQL would might choose a table scan
over an index seek based on the rowcount estimates.  A table scan would
be the best plan if the parameter value was 0, but unfortunately it

stored proc for more typical parameters suffers.

In SQL 7.0 or 2000, suppose you executed this proc for the first time

10".  Parameter sniffing allows SQL to insert the known value of


compile a plan that is tailored to the class of parameters that is
actually passed into the proc, so for example it might select an index
seek instead of a table scan based on the smaller estimated rowcount --

execution plans, but a key requirement for everything to work as expected
is that the parameter values used for compilation be "typical".

In your case, the problem is that you have default NULL values for your

the parameter values are changed inside the stored proc before they are
used -- as a result NULL will never actually be used to search the
column.  If the first execution of this stored proc doesn't pass in an

be NULL.  When SQL compiles the plan for this sp it substitutes NULL for

Unfortunately, after execution begins the first thing the stored proc

unfortunately SQL doesn't know about this at compile time.  Because NULL
is a very atypical parameter value, the plan that SQL generates may not
be a good one for the new value of the parameter that is assigned at
execution time.

So, the bottom line is that if you assign defaults to your sp parameters
and later use those same parameters in a query, the defaults should be
"typical" because they will be used during plan generation.  If you must
use defaults and business logic dictates that they be atypical (as may be
the case here if app modifications are not an option), there are two
possible solutions if you determine that the substitution of atypical
parameter values is causing bad plans:

1. "Disable" parameter sniffing by using local DECLARE'd variables that
you SET equal to the parameters inside the stored proc, and use the local
variables instead of the offending parameters in the queries. This is the
solution that you found yourself.  SQL can't use parameter sniffing in
this case so it must make some guesses, but in this case the guess based
on average column density is better than the plan based on a specific but
"wrong" parameter value (NULL).

2. Nest the affected queries somehow so that they run within a different
context that will require a distinct execution plan.  There are several
possibilities here. for example:
    a. Put the affected queries in a different "child" stored proc.  If

has been changed to its final value, parameter sniffing will suddenly
become your friend because the value SQL uses to compile the queries
inside the child stored proc is the actual value that will be used in the
query.
    b. Use sp_executesql to execute the affected queries.  The plan won't
be generated until the sp_executesql stmt actually runs, which is of
course after the parameter values have been changed.

An equivalent approach would be to put the query in a child stored proc
just like 2.a, but execute it within the parent proc with EXEC WITH
RECOMPILE.

Option #1 seems to have worked well for you in this case, although
sometimes one of the options in #2 is a preferable choice.  Here are some
guidelines, although when you're dealing with something as complicated as
the query optimizer experimentation is often the best approach <g>:

   - If you have only one "class" (defined as values that have similar
density in the table) of actual parameter value that is used within a
query (even if there are other classes of data in the base table that are
never or rarely searched on), 2.a. or 2.b is probably the best option.
This is because these options permit the actual parameter values to be
used during compilation which should result in the most efficient query
plan for that class of parameter.
   - If you have multiple "classes" of parameter value (for example, for
the column being searched, half the table data is NULL, the other half
are unique integers, and you may do searches on either class), 2.c can be
effective.  The downside is that a new plan for the query must be
compiled on each execution, but the upside is that the plan will always
be tailored to the parameter value being used for that particular
execution.  This is best when there is no single execution plan that
provides acceptable execution time for all classes of parameters.

HTH -
Bart
------------
Bart Duncan
Microsoft SQL Server Support

Please reply to the newsgroup only - thanks.

This posting is provided "AS IS" with no warranties, and confers no
rights.

--

Andrew J. Kelly
SQL Server MVP


Quote:
> Hi all,

> I need to force the SQL Server to use specific index (strange thing - in
QA
> it uses good index, when I place it in SP, uses wrong one...). For this
> reason, I used ... WITH(INDEX(...)) ... in SQL query. Again, in QA it
works
> fine, but when I place it in SP, I get this message:
> "Query processor could not produce a query plan because of the hints
defined
> in this query. Resubmit the query without specifying any hints and without
> using SET FORCEPLAN."  (error 8622)

> I tried to put these SETs inside:
> SET ANSI_NULLS ON
> SET ANSI_PADDING ON
> SET ANSI_WARNINGS ON
> SET ARITHABORT ON
> SET CONCAT_NULL_YIELDS_NULL ON
> SET QUOTED_IDENTIFIER  ON
> SET NUMERIC_ROUNDABORT OFF

> but it doesn't help :-(((
> I tried to put "with recompile" to SP - doesn't help.

> I have no idea what the problem can be.
> Any ideas very welcome.

> Thank you,
>     Petr Langer



Tue, 26 Jul 2005 08:51:11 GMT
 Query processor could not produce a query plan...
Andrew, thank you VERY MUCH for all ideas in your long response.
I have finally solved the problem with use of it.
I am using index on computed column (checksum of varchar column) but SP was
not using it, so I copied it from Ent. Manager to QA, I removed it and I
put:
SET ANSI_NULLS ON
SET ANSI_PADDING ON
SET ANSI_WARNINGS ON
SET ARITHABORT ON
SET CONCAT_NULL_YIELDS_NULL ON
SET QUOTED_IDENTIFIER  ON
SET NUMERIC_ROUNDABORT OFF
go
CREATE PROCEDURE ...

...
go

AND - it works great!
From more than 7 minutes to about 20 seconds!
Uff, still lot to learn... :-)

Thanks again,
    Petr



Quote:
> The problem with the parameters might be caused by one of the things
> mentioned by Bart in the section below.  But you should remove ALL query
> hints and SET's from in the stored procedure and let the optimizer do it's
> thing.  Including these SET statements that you listed may force the query
> to be recompiled each time its run, especially if the current connection
> settings are different than those.  If you need any of these a specific
way
> and it isn't already defaulted that way then issue the SET statements
> outside of the CREATE PROCEDURE block.

> The reason for the performance difference stems from a feature called
> "parameter sniffing".  Consider a stored proc defined as follows:



>      GO

> Keep in mind that the server has to compile a complete execution plan for
> the proc before the proc begins to execute.  In 6.5, at compile time SQL

> when compiling a plan.  Suppose all of the actual parameter values for

> integers that were greater than 0, but suppose 40% of the [c1] values in
> [table1] were, in fact, 0.  SQL would use the average density of the
> column to estimate the number of rows that this predicate would return;
> this would be an overestimate, and SQL would might choose a table scan
> over an index seek based on the rowcount estimates.  A table scan would
> be the best plan if the parameter value was 0, but unfortunately it

> stored proc for more typical parameters suffers.

> In SQL 7.0 or 2000, suppose you executed this proc for the first time

> 10".  Parameter sniffing allows SQL to insert the known value of


> compile a plan that is tailored to the class of parameters that is
> actually passed into the proc, so for example it might select an index
> seek instead of a table scan based on the smaller estimated rowcount --
> this is a good thing if most of the time 0 is not the value passed as

> execution plans, but a key requirement for everything to work as expected
> is that the parameter values used for compilation be "typical".

> In your case, the problem is that you have default NULL values for your

> the parameter values are changed inside the stored proc before they are
> used -- as a result NULL will never actually be used to search the
> column.  If the first execution of this stored proc doesn't pass in an

> be NULL.  When SQL compiles the plan for this sp it substitutes NULL for

> Unfortunately, after execution begins the first thing the stored proc

> unfortunately SQL doesn't know about this at compile time.  Because NULL
> is a very atypical parameter value, the plan that SQL generates may not
> be a good one for the new value of the parameter that is assigned at
> execution time.

> So, the bottom line is that if you assign defaults to your sp parameters
> and later use those same parameters in a query, the defaults should be
> "typical" because they will be used during plan generation.  If you must
> use defaults and business logic dictates that they be atypical (as may be
> the case here if app modifications are not an option), there are two
> possible solutions if you determine that the substitution of atypical
> parameter values is causing bad plans:

> 1. "Disable" parameter sniffing by using local DECLARE'd variables that
> you SET equal to the parameters inside the stored proc, and use the local
> variables instead of the offending parameters in the queries. This is the
> solution that you found yourself.  SQL can't use parameter sniffing in
> this case so it must make some guesses, but in this case the guess based
> on average column density is better than the plan based on a specific but
> "wrong" parameter value (NULL).

> 2. Nest the affected queries somehow so that they run within a different
> context that will require a distinct execution plan.  There are several
> possibilities here. for example:
>     a. Put the affected queries in a different "child" stored proc.  If

> has been changed to its final value, parameter sniffing will suddenly
> become your friend because the value SQL uses to compile the queries
> inside the child stored proc is the actual value that will be used in the
> query.
>     b. Use sp_executesql to execute the affected queries.  The plan won't
> be generated until the sp_executesql stmt actually runs, which is of
> course after the parameter values have been changed.

> An equivalent approach would be to put the query in a child stored proc
> just like 2.a, but execute it within the parent proc with EXEC WITH
> RECOMPILE.

> Option #1 seems to have worked well for you in this case, although
> sometimes one of the options in #2 is a preferable choice.  Here are some
> guidelines, although when you're dealing with something as complicated as
> the query optimizer experimentation is often the best approach <g>:

>    - If you have only one "class" (defined as values that have similar
> density in the table) of actual parameter value that is used within a
> query (even if there are other classes of data in the base table that are
> never or rarely searched on), 2.a. or 2.b is probably the best option.
> This is because these options permit the actual parameter values to be
> used during compilation which should result in the most efficient query
> plan for that class of parameter.
>    - If you have multiple "classes" of parameter value (for example, for
> the column being searched, half the table data is NULL, the other half
> are unique integers, and you may do searches on either class), 2.c can be
> effective.  The downside is that a new plan for the query must be
> compiled on each execution, but the upside is that the plan will always
> be tailored to the parameter value being used for that particular
> execution.  This is best when there is no single execution plan that
> provides acceptable execution time for all classes of parameters.

> HTH -
> Bart
> ------------
> Bart Duncan
> Microsoft SQL Server Support

> Please reply to the newsgroup only - thanks.

> This posting is provided "AS IS" with no warranties, and confers no
> rights.

> --

> Andrew J. Kelly
> SQL Server MVP



> > Hi all,

> > I need to force the SQL Server to use specific index (strange thing - in
> QA
> > it uses good index, when I place it in SP, uses wrong one...). For this
> > reason, I used ... WITH(INDEX(...)) ... in SQL query. Again, in QA it
> works
> > fine, but when I place it in SP, I get this message:
> > "Query processor could not produce a query plan because of the hints
> defined
> > in this query. Resubmit the query without specifying any hints and
without
> > using SET FORCEPLAN."  (error 8622)

> > I tried to put these SETs inside:
> > SET ANSI_NULLS ON
> > SET ANSI_PADDING ON
> > SET ANSI_WARNINGS ON
> > SET ARITHABORT ON
> > SET CONCAT_NULL_YIELDS_NULL ON
> > SET QUOTED_IDENTIFIER  ON
> > SET NUMERIC_ROUNDABORT OFF

> > but it doesn't help :-(((
> > I tried to put "with recompile" to SP - doesn't help.

> > I have no idea what the problem can be.
> > Any ideas very welcome.

> > Thank you,
> >     Petr Langer



Tue, 26 Jul 2005 17:23:56 GMT
 
 [ 3 post ] 

 Relevant Pages 

1. Replication Error:The query processor could not produce a query plan from the op

2. [sql server] The query processor could not produce a query plan

3. Error 8623: Internal Query Processor Error: The query processor could not produce a query plan.

4. Error while replicating - query processor could not produce a query plan....

5. The query processor could not produce a query plan.

6. Error 8623 - query processor could not producde a query plan

7. Error: Could not produce a query plan!

8. The query processor could not start the necessary thread resources for parallel query execution

9. The query processor could not start the necessary thread resources for parallel query execution

10. SQL Server 2000 with SP1 Cannot produce query plan with SELECT INTO #Table

11. Procedure produces different query plans

12. Couldn't produce query plan


 
Powered by phpBB® Forum Software