September 2, 2012 at 7:37 pm
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?
September 2, 2012 at 7:48 pm
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 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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
September 2, 2012 at 10:32 pm
double post... removed.
September 2, 2012 at 10:32 pm
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.
September 2, 2012 at 10:59 pm
You need to call DelimitedSplit8K (not dbo.Table1) as I did. Find it in the link I provided.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
September 3, 2012 at 12:05 am
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,',')
September 3, 2012 at 12:23 am
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 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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
September 3, 2012 at 12:24 am
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.
September 3, 2012 at 1:21 am
Happy to be of service. You're welcome.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
September 4, 2012 at 8:49 am
Tava (9/3/2012)
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.
But do you UNDERSTAND it? It is great that you have it working but unless you understand it you are only half way done. You are the person getting the phone call at 3am when your production system is down. If you don't understand it then you need to go back and read that article over and over until you do.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
September 4, 2012 at 9:44 am
Not having anything to test with, this is a possible alternative that converts your multi-statement tvf into an inline tvf. Test it out and compare it to what you already have (you may want to change the name to do some head to head comparisions).
drop function dbo.fDayCount;
go
CREATE FUNCTION [dbo].[fDayCount]
(
@WorkDate DATETIME
)
RETURNS @returntable TABLE
AS
return(
SELECT
workdate,
companyID
FROM
dbo.table1
INNER JOIN dbo.table2
ON table1.a = table2.a
WHERE
date = @date
AND companyid IN(select
ds.Item
from
dbo.config
cross apply dbo.DelimtedSplit8K(CompID,',') ds
where
configva = 'compidstring')
);
go
September 4, 2012 at 9:48 am
CELKO (9/3/2012)
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. :w00t: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. 🙂
Let's see, your view may take less space, but fails in some regards. The first is the use of the old ANSI-89 style join instead of the newer ANSI-92 style join. I though you were all for using standards? You should consider updating to the newer standard. In my opinion it makes code more readable be separating the JOIN criteria from the filter criteria in the FROM clause.
Also, there really is nothing wrong with listing each column on its own line, in fact I prefer that as a coding style. Apparently so do many of the routines used to automatically format code. Personally, putting as many columns on one line leads to more difficult to read code.
September 4, 2012 at 2:23 pm
CELKO (9/3/2012)
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
Absolutely incorrect on all counts. This an Inline Table Value Function that the optimizer weaves into the code as if it were a view. "Good SQL [sic]" should always use them for this type of thing. It doesn't matter if they're proprietary because, except for the most basic of CRUD, true portability is a bloody myth. They ARE relational because they work like a view. And it would seem that the only one stuck in the 1960's is you because you didn't know this. 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
September 4, 2012 at 3:55 pm
Sean Lange (9/4/2012)
Tava (9/3/2012)
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.But do you UNDERSTAND it? It is great that you have it working but unless you understand it you are only half way done. You are the person getting the phone call at 3am when your production system is down. If you don't understand it then you need to go back and read that article over and over until you do.
I know, I didn't quiet understand it all and that's just because I'm new to all this, what I did instead was (might not be the best method) took it out of the function and placed it into the Stored Proc instead.
We had the stored proc calling this function. So that was removed and code was modified.
September 5, 2012 at 7:32 am
Tava (9/4/2012)
Sean Lange (9/4/2012)
Tava (9/3/2012)
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.But do you UNDERSTAND it? It is great that you have it working but unless you understand it you are only half way done. You are the person getting the phone call at 3am when your production system is down. If you don't understand it then you need to go back and read that article over and over until you do.
I know, I didn't quiet understand it all and that's just because I'm new to all this, what I did instead was (might not be the best method) took it out of the function and placed it into the Stored Proc instead.
We had the stored proc calling this function. So that was removed and code was modified.
If it were me I would put it back in the function. That way you can use it elsewhere.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
Viewing 15 posts - 1 through 14 (of 14 total)
You must be logged in to reply to this topic. Login to reply