Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Find integer at end of a string. There *must* be a better solution ?


Find integer at end of a string. There *must* be a better solution ?

Author
Message
TomThomson
TomThomson
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10696 Visits: 11991
Thorkil Johansen (7/25/2013)

Someone said: Looks like 123.4 is not an integer, so -1 should be returned.

Yes, that's right


So if the string were xyz-1-2.3-2 what's the required answer?
2, because -2 are the last two characters? or -1 because -1-2.3-2 isn't an integer?

Tom

Thorkil Johansen
Thorkil Johansen
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 50
Hi Tom

I have the assumption that only one hyphen will be in the string, but if the case was
xyz-1-2.3-2
then 2 would be the right answer...

To sharpen a little: "The integer to the right of the last hyphen in the string"
/T
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
My contribution ain't exactly pretty but might work for you:


with tmp as (
select x = 'some text-1'
union select x = 'some text-123'
union select x = 'some text-123.4'
union select x = 'some text 123'
union select x = 'some text-'
union select x = 'some text'
union select x = 'some text-xyz'
)
SELECT x,
CASE
WHEN EndStr IN (0,1) THEN -1
WHEN 0=ISNUMERIC(RIGHT(x, EndStr-1)) THEN -1
WHEN FLOOR(RIGHT(x, EndStr-1)) = RIGHT(x, EndStr-1)
THEN CAST(RIGHT(x, EndStr-1) AS INT)
ELSE -1
END
FROM tmp a
CROSS APPLY (SELECT CHARINDEX('-', REVERSE(x))) b(EndStr);





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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Cadavre
Cadavre
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2594 Visits: 8436
Forgive me for my simplistic approach :-D

WITH tmp
AS (SELECT x = 'some text-1'
UNION ALL SELECT x = 'some text-123'
UNION ALL SELECT x = 'some text-123.4'
UNION ALL SELECT x = 'some text 123'
UNION ALL SELECT x = 'some text-'
UNION ALL SELECT x = 'some text'
UNION ALL SELECT x = 'some text-xyz'
UNION ALL SELECT x = 'xyz-1-2.3-2'
)
SELECT *,
CASE WHEN x LIKE '%-[0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
ELSE - 1 END
FROM tmp;




--EDIT--
Quick performance check. Note, I borrowed Dwain's method for grabbing the last digits as I figured it'd be quicker than the reverse reverse as SQL is not good at string manipulation.

SET NOCOUNT ON;

IF object_id('tempdb..#testEnvironment') IS NOT NULL
BEGIN
DROP TABLE #testEnvironment;
END;

--1,000,000 Random rows of data
SELECT TOP 1000000 IDENTITY(INT,1,1) AS ID,
'some text'+ CASE WHEN (ABS(CHECKSUM(NEWID())) % 100) + 1 >= 50 THEN '-' ELSE '' END +
CASE WHEN (ABS(CHECKSUM(NEWID())) % 100) + 1 >= 50 AND CHARINDEX('.',CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX))) > 3
THEN SUBSTRING(CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX)),0,CHARINDEX('.',CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX)))-1)
ELSE CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX)) END AS x
INTO #testEnvironment
FROM master.dbo.syscolumns sc1, master.dbo.syscolumns sc2, master.dbo.syscolumns sc3;

DECLARE @Loop CHAR(1) = '0', @HOLDER INT, @Duration CHAR(12), @StartTime DATETIME;

WHILE @Loop <= 5
BEGIN
RAISERROR('Loop: %s',0,1,@Loop) WITH NOWAIT;
RAISERROR('============',0,1) WITH NOWAIT;
DBCC FREEPROCCACHE WITH NO_INFOMSGS;
DBCC DROPCLEANBUFFERS WITH NO_INFOMSGS;

   SELECT @StartTime = GETDATE();

SELECT @HOLDER =
CASE WHEN x LIKE '%-[0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
ELSE - 1 END
FROM #testEnvironment;

SELECT @Duration = CONVERT(CHAR(12),GETDATE()-@StartTime,114);
RAISERROR('BIG CASE Duration: %s',0,1,@Duration) WITH NOWAIT;

DBCC FREEPROCCACHE WITH NO_INFOMSGS;
DBCC DROPCLEANBUFFERS WITH NO_INFOMSGS;

SELECT @StartTime = GETDATE();


SELECT @HOLDER =
CASE
WHEN EndStr IN (0,1) THEN -1
WHEN 0=ISNUMERIC(RIGHT(x, EndStr-1)) THEN -1
WHEN FLOOR(RIGHT(x, EndStr-1)) = RIGHT(x, EndStr-1)
THEN CAST(RIGHT(x, EndStr-1) AS INT)
ELSE -1
END
FROM #testEnvironment a
CROSS APPLY (SELECT CHARINDEX('-', REVERSE(x))) b(EndStr);

SELECT @Duration = CONVERT(CHAR(12),GETDATE()-@StartTime,114);
RAISERROR('COOL MATHS Duration: %s',0,1,@Duration) WITH NOWAIT;

SET @Loop = @Loop + 1;
END



Loop: 0
============
BIG CASE Duration: 00:00:51:533
COOL MATHS Duration: 00:00:12:057
Loop: 1
============
BIG CASE Duration: 00:00:52:107
COOL MATHS Duration: 00:00:11:967
Loop: 2
============
BIG CASE Duration: 00:00:53:087
COOL MATHS Duration: 00:00:12:240
Loop: 3
============
BIG CASE Duration: 00:00:52:077
COOL MATHS Duration: 00:00:12:100
Loop: 4
============
BIG CASE Duration: 00:00:51:477
COOL MATHS Duration: 00:00:11:970
Loop: 5
============
BIG CASE Duration: 00:00:52:023
COOL MATHS Duration: 00:00:12:010


Pretty consistent win for Dwain's solution over mine. The results show a similar pattern with an index (big case took around 50 seconds but the maths reduced down to around 7 seconds).


Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14931 Visits: 38920
Cadavre I love your new signature with the nolock pointers! just noticed it today.

Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Cadavre
Cadavre
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2594 Visits: 8436
Lowell (7/26/2013)
Cadavre I love your new signature with the nolock pointers! just noticed it today.


I added it after the last time I had to dig them all out :-)


Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
Erland Sommarskog
Erland Sommarskog
SSC Eights!
SSC Eights! (931 reputation)SSC Eights! (931 reputation)SSC Eights! (931 reputation)SSC Eights! (931 reputation)SSC Eights! (931 reputation)SSC Eights! (931 reputation)SSC Eights! (931 reputation)SSC Eights! (931 reputation)

Group: General Forum Members
Points: 931 Visits: 866
with tmp as (
select x = 'some text-1'
union select x = 'some text-123'
union select x = 'some text-123.4'
union select x = 'some text 123'
union select x = 'some text-'
union select x = 'some text'
union select x = 'some text-xyz'
)
select * ,
    coalesce( TRY_CONVERT(int,
nullif(SUBSTRING(x, 1 + nullif(CHARINDEX('-',x), 0), LEN(x)),
'')),
-1)
from tmp



LEN(x) - charindex can be reduced to LEN(x), since you want the rest of the string. I removed the outer CASE and replaced it with two NULLIF. One to capture that therte are no hyphen at all, and one to capture that there are only spaces after the hyphen.

There was a question about multiple hyphens. My assumptions from the original post is that the integer should be from the hyphen to the end of the string, so Abc-2-3 should return -1.

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
Cadavre - I love the name you gave mine: "COOL MATHS/"

I suspect it might have a bug though where the string ends like -$ (might show 0).


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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Thorkil Johansen
Thorkil Johansen
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 50
Nice one... :-)

I have the assumption that only one hyphen will be in the string, but if the case was
xyz-1-2.3-2
then 2 would be the right answer...

To sharpen a little: "The integer to the right of the last hyphen in the string"
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44968 Visits: 39862
The use of IsNumeric in onne of the solutions serves as a reminder that there are a whole lot of things that look like numbers to SQLServer. Here's some updated test data to see what I mean...

with tmp as 
(
SELECT x = 'some text-1'
UNION ALL SELECT x = 'some text-123'
UNION ALL SELECT x = 'some text-123.4'
UNION ALL SELECT x = 'some text 123'
UNION ALL SELECT x = 'some text-'
UNION ALL SELECT x = 'some text- ' --Added this for possible CHAR values
UNION ALL SELECT x = 'some text- 123 ' --Added "stray bullet"
UNION ALL SELECT x = 'some text-123 456' --Added "stray bullet"
UNION ALL SELECT x = 'some text-123d4' --Added "stray bullet"
UNION ALL SELECT x = 'some text-123e4' --Added "stray bullet"
UNION ALL SELECT x = 'some text-$1,234' --Added "stray bullet"
UNION ALL SELECT x = 'some text-1,234' --Added "stray bullet"
UNION ALL SELECT x = 'some text-0x1234,' --Added "stray bullet"
UNION ALL SELECT x = 'some text'
UNION ALL SELECT x = 'some text-xyz'
)
... put your code here ...



--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search