Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

using IN statment & a string variable. Expand / Collapse
Author
Message
Posted Sunday, September 2, 2012 7:37 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Sunday, April 27, 2014 8:38 PM
Points: 90, Visits: 420
Hi,

I need some assistance and i've read multiple answers which are very similar but just not sure how to tie it in with my code as what I've done has failed. I have a newly created function & below is a snippet of the code it's not the whole lot but crucial parts to understand and provide advice.

----------------------------------------

ALTER FUNCTION [dbo].[fDayCount]
(
@WorkDate DATETIME
)

RETURNS
@returntable TABLE
(
WorkDate DATETIME,
CompanyID VARCHAR(255)
)

AS
BEGIN

DECLARE @CompanyID varchar(50)

SET @CompanyID =
(
SELECT
CompID
FROM
dbo.config
WHERE
configva = 'compidstring'
)

INSERT @returntable
(
WorkDate
CompanyID
)

SELECT
workdate,
@companyID
FROM
dbo.table1
INNER JOIN
dbo.table2
ON
table1.a = table2.a
WHERE
date = @date
AND
companyid IN(@CompanyID)

RETURN
END

----------------------------------------------------

@CompanyID is a string of all companies that are relevant e.g. '1','33',97' ... i could hardcode this inside the IN statement and it works but this is changed from time to time which means the statement will need to be updated every so often, while the variable will be updated from SSIS feeds.

I've read doing it as SET @SQL = ' statement' + @varible +' )' but just not working for me.

Any idea on how to get around this?


Post #1353303
Posted Sunday, September 2, 2012 7:48 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:30 AM
Points: 3,420, Visits: 5,348
Try changing:

AND
companyid IN(@CompanyID)


To:

AND
companyid IN(SELECT item FROM dbo.DelimitedSplit8K(@CompanyID, ','))


Where DelimitedSplit8K can be found here:
http://www.sqlservercentral.com/articles/Tally+Table/72993/



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353305
Posted Sunday, September 2, 2012 10:32 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Sunday, April 27, 2014 8:38 PM
Points: 90, Visits: 420
double post... removed.
Post #1353329
Posted Sunday, September 2, 2012 10:32 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Sunday, April 27, 2014 8:38 PM
Points: 90, Visits: 420
When using that example it produced an error

IN
(
SELECT ConfiguredValue
FROM
dbo.table1(@CompanyID, ',')
)


Parameters supplied for object 'dbo.table1' which is not a function. If the parameters are intended as a table hint, a WITH keyword is required.
Post #1353330
Posted Sunday, September 2, 2012 10:59 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:30 AM
Points: 3,420, Visits: 5,348
You need to call DelimitedSplit8K (not dbo.Table1) as I did. Find it in the link I provided.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353334
Posted Monday, September 3, 2012 12:05 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Sunday, April 27, 2014 8:38 PM
Points: 90, Visits: 420
sorry just a little confused. So i have to create the function (as per the script) & once created call it in the way you did to my reply.

1. CREATE FUNCTION [dbo].[DelimitedSplit8K]
2. Perform the IN ( select 'column' from dbo.delimitedSplit,',')

Post #1353350
Posted Monday, September 3, 2012 12:23 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:30 AM
Points: 3,420, Visits: 5,348
Tava (9/3/2012)
sorry just a little confused. So i have to create the function (as per the script) & once created call it in the way you did to my reply.

1. CREATE FUNCTION [dbo].[DelimitedSplit8K]

Yes

Tava (9/3/2012)
2. Perform the IN ( select 'column' from dbo.delimitedSplit,',')


No. You must:

SELECT item FROM dbo.DelimitedSplit8K(@CompanyID, ',')


Item is the name of the column returned by DelimitedSplit8K that you need to look in.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353358
Posted Monday, September 3, 2012 12:24 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Sunday, April 27, 2014 8:38 PM
Points: 90, Visits: 420
excellent, I got it working, created the Function & in the subquery now getting the results i wanted... really appreciate your help on this... no way i would have solved it.

IN
(
SELECT
Item
FROM
dbo.fDelimitedSplit8K(@CompanyID, ',')
)

Thanks again.
Post #1353359
Posted Monday, September 3, 2012 1:21 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:30 AM
Points: 3,420, Visits: 5,348
Happy to be of service. You're welcome.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1353365
Posted Monday, September 3, 2012 4:23 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 8:24 PM
Points: 1,945, Visits: 3,017
You gave us no DDL, so this will be harder than it should. I assume that you want to get rid of this function. Good SQL never use them; they are proprietary, non-relational, screw up the optimizer and scream to the world that the author is still stuck in 1960's BASIC, right down to the “f_”, “fn_”, “udf_” prefixes that were required by FORTRAN II and BASIC.

Since we have VIEWs in SQL, a UDF that returns a table is the worst way to program SQL; but it lets BASIC avoid leaning how to do it right. Write a VIEW.

We use the DUNS for company identifiers; it is the industry standard. Can you give me a 255 character example of your company_id? When you invite garbage data with absurdly sized columns, you will get it. I also see the magic default VARCHAR(50) declarations from ACCESS.

Is the company identifier of a client or a supplier or what? In COBOL, which is what you are actually writing, the hierarchical record structure would would qualify the field; but SQL has tables with rows and columns, not records and fielsd.

I also see that you layout your code as if you were still using punch cards; each parens, data element, etc on a separate card (line). That let us re-arrange the deck on the fly. Today, we use a “pretty printer” and make the code human readable instead.

CREATE VIEW Count_Somethings_Days (work_date, client_duns)
AS
SELECT work_date, client_duns
FROM dbo.Table1, dbo.Table2 -- not real names!
WHERE Table1.vague_something = Table2.vague_something
AND client_duns IN (..);

Yes, you actually have to hard code the list, if it is what defines the set your want. Yes, I know it worked that way in 1960's BASIC, but SQL is compiled and not interpreted.

If you want this to change infrequently, put their DUNS in a table and use “client_duns IN (SELECT client_duns FROM Bankrupt_Companies)”in the VIEW. There is also the long parameter list idiom, if you want to make this into a stored procedure.

My guess is that you are about 2-3 years away from un-learning bad habits and old languages to be an SQL programmer. Keep at it and read everything you can find, starting with an intro to Set Theory and Logic. Eventually, you will get to ISO Standards which are boring as hell.



Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1353644
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse