Skip to content

Commit 6a98aad

Browse files
authored
Add files via upload
1 parent 6f5c123 commit 6a98aad

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

50 files changed

+4889
-0
lines changed

User_Defined_Function/FN_SPLIT.sql

+480
Large diffs are not rendered by default.

User_Defined_Function/README.md

+104
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,104 @@
1+
# Microsoft SQL Server functions
2+
Start all functions from if exist statement:
3+
```sql
4+
IF OBJECT_ID('dbo.udf_FunctionName', 'FN') IS NULL
5+
EXECUTE ('CREATE FUNCTION dbo.udf_FunctionName() RETURNS INT AS BEGIN RETURN 1 END;');
6+
GO
7+
8+
9+
ALTER FUNCTION dbo.udf_FunctionName(
10+
```
11+
12+
It helps to save all grants for function (analog `CREATE OR REPLACE PROCEDURE` in [Oracle](http://docs.oracle.com/cd/B19306_01/server.102/b14200/statements_6009.htm 'Offical Oracle Documentation')).
13+
14+
15+
## [udf_PatExclude8K](udf_PatExclude8K.sql)
16+
Author: Alan Burstein<br/>
17+
Original link: http://www.sqlservercentral.com/scripts/T-SQL/117890/<br />
18+
Tested on SQL Server version: 2008/2012/2014/2016<br />
19+
Purpose: Given a string (@String) and a pattern (@Pattern) of characters to remove, remove the patterned characters from the string.<br />
20+
Usage:
21+
```sql
22+
--===== Basic Syntax Example
23+
SELECT CleanedString
24+
FROM dbo.udf_PatExclude8K(@String, @Pattern);
25+
26+
--===== Remove all but Alpha characters
27+
SELECT CleanedString
28+
FROM dbo.SomeTable st
29+
CROSS APPLY dbo.udf_PatExclude8K(st.SomeString,'%[^A-Za-z]%');
30+
31+
--===== Remove all but Numeric digits
32+
SELECT CleanedString
33+
FROM dbo.SomeTable st
34+
CROSS APPLY dbo.udf_PatExclude8K(st.SomeString,'%[^0-9]%');
35+
```
36+
37+
38+
## [udf_GetNumsAB](udf_GetNumsAB.sql)
39+
Author: Alan Burstein<br/>
40+
Original link: http://www.sqlservercentral.com/scripts/Set+Based/139370/<br />
41+
Tested on SQL Server version: 2008/2012/2014/2016<br />
42+
Purpose: Creates up to 100,544,625 sequential numbers beginning with @low and ending with @high. Used to replace iterative methods such as loops, cursors and recursive CTEs to solve SQL problems. Based on Itzik Ben-Gan's getnums function with some tweeks and enhancements and added functionality. The logic for getting rn to begin at 0 or 1 is based comes from Jeff Moden's fnTally function.<br />
43+
Usage:
44+
```sql
45+
--===== 1. Using RN (rownumber)
46+
-- (1.1) The best way to get the numbers 1,2,3...@high (e.g. 1 to 5):
47+
SELECT RN FROM dbo.udf_GetNumsAB(1,5,1,1);
48+
49+
-- (1.2) The best way to get the numbers 0,1,2...@high-1 (e.g. 0 to 5):
50+
SELECT RN FROM dbo.udf_GetNumsAB(0,5,1,0);
51+
52+
--===== 2. Using N1
53+
-- (2.1) To begin with numbers other than 0 or 1 use N1 (e.g. -3 to 3):
54+
SELECT N1 FROM dbo.udf_GetNumsAB(-3,3,1,1);
55+
56+
-- (2.2) ROW_NUMBER() is built in. If you want a ROW_NUMBER() include RN:
57+
SELECT RN, N1 FROM dbo.udf_GetNumsAB(-3,3,1,1);
58+
59+
-- (2.3) If you wanted a ROW_NUMBER() that started at 0 you would do this:
60+
SELECT RN, N1 FROM dbo.udf_GetNumsAB(-3,3,1,0);
61+
62+
--===== 3. Using N2 and @gap
63+
-- (3.1) To get 0,10,20,30...100, set @low to 0, @high to 100 and @gap to 10:
64+
SELECT N1 FROM dbo.udf_GetNumsAB(0,100,10,1);
65+
66+
-- (3.2) Note that N2=N1+@gap; this allows you to create a sequence of ranges.
67+
-- For example, to get (0,10),(10,20),(20,30).... (90,100):
68+
SELECT N1, N2 FROM dbo.udf_GetNumsAB(0,90,10,1);
69+
70+
-- (3.3) Remember that a rownumber is included and it can begin at 0 or 1:
71+
SELECT RN, N1, N2 FROM dbo.udf_GetNumsAB(0,90,10,1);
72+
73+
--===== (4) A real life example using RN, N1 and N2:
74+
-- Beginning with @StartDate, to generate ranges of weeks that occur between
75+
-- @startDate & @EndDate:
76+
```
77+
78+
79+
## [udf_Is16digitValidCard](udf_Is16digitValidCard.sql)
80+
Author: Phil Factor<br/>
81+
Original link: https://www.simple-talk.com/blogs/2016/02/16/the-luhn-algorithm-in-sql/<br />
82+
Tested on SQL Server version: 2008/2012/2014/2016<br />
83+
Description: The Luhn test is used by most credit card companies to check the basic validity of a credit card number. It is not an anti-fraud measure but a quick check on data corruption. It still allows any digits that are odd or even to be switched in the sequence. Most credit cards are compatible with Luhn algorithm.
84+
1. It is often applied to SSNs, company organization numbers, and OCR numbers for internet payments. The algorithm is simple.
85+
2. Take out the spaces from the string containing the credit card numbers
86+
3. Reverse the string containing the credit card numbers.
87+
4. Sum every digit whose order in the sequence is an odd number (1,3,5,7 …) to create a partial sum s1
88+
5. Multiply each even digit by two, and then sum the digits of the number if the answer is greater than nine. (e,g if digit is 8 then 8*2=16, then add the resulting digits: 1+6=7).
89+
6. Sum the partial sums of the even digits to form s2
90+
7. if s1 + s2 ends in zero then the original number is in the form of a valid credit card number as verified by the Luhn test.
91+
92+
93+
## [udf_IsValidCard](udf_IsValidCard.sql)
94+
Author: Phil Factor<br/>
95+
Original link: https://www.simple-talk.com/blogs/2016/02/16/the-luhn-algorithm-in-sql/<br />
96+
Tested on SQL Server version: 2008/2012/2014/2016<br />
97+
Description: The Luhn test is used by most credit card companies to check the basic validity of a credit card number. It is not an anti-fraud measure but a quick check on data corruption. It still allows any digits that are odd or even to be switched in the sequence. Most credit cards are compatible with Luhn algorithm.
98+
1. It is often applied to SSNs, company organization numbers, and OCR numbers for internet payments. The algorithm is simple.
99+
2. Take out the spaces from the string containing the credit card numbers
100+
3. Reverse the string containing the credit card numbers.
101+
4. Sum every digit whose order in the sequence is an odd number (1,3,5,7 …) to create a partial sum s1
102+
5. Multiply each even digit by two, and then sum the digits of the number if the answer is greater than nine. (e,g if digit is 8 then 8*2=16, then add the resulting digits: 1+6=7).
103+
6. Sum the partial sums of the even digits to form s2
104+
7. if s1 + s2 ends in zero then the original number is in the form of a valid credit card number as verified by the Luhn test.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
IF OBJECT_ID('dbo.udf_ConvertHexLSN') IS NULL
2+
EXECUTE ('CREATE FUNCTION udf_ConvertHexLSN() RETURNS TABLE AS RETURN SELECT 1 AS A;');
3+
GO
4+
5+
6+
ALTER FUNCTION dbo.udf_ConvertHexLSN(
7+
@lsnc varchar(25)
8+
)
9+
/*
10+
Author: Max Vernon
11+
Original link: https://www.sqlserverscience.com/internals/convert-lsn-hex-decimal/
12+
13+
SELECT * FROM dbo.udf_ConvertHexLSN('00000268:0000356c:0001');
14+
*/
15+
RETURNS TABLE
16+
WITH SCHEMABINDING
17+
AS
18+
RETURN
19+
(
20+
SELECT TOP(1)
21+
LSNd = CONVERT(varchar(8), CONVERT(int, CONVERT(varbinary(8), '0x' + CONVERT(varchar(10), LEFT(@lsnc, 8), 0), 1), 1))
22+
+ ':' + CONVERT(varchar(8), CONVERT(int, CONVERT(varbinary(8), '0x' + CONVERT(varchar(10), SUBSTRING(@lsnc, 10, 8), 0), 1)), 1)
23+
+ ':' + CONVERT(varchar(8), CONVERT(int, CONVERT(varbinary(8), '0x' + CONVERT(varchar(10), RIGHT(@lsnc, 4), 0), 1), 1))
24+
);
25+
GO
+64
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,64 @@
1+
IF OBJECT_ID('dbo.udf_InitCap') IS NULL
2+
EXECUTE ('CREATE FUNCTION dbo.udf_InitCap() RETURNS nvarchar(max) AS RETURN SELECT 1 AS A;');
3+
GO
4+
5+
ALTER FUNCTION dbo.udf_InitCap(
6+
@StrStr nvarchar(max)
7+
)
8+
/*
9+
SELECT dbo.udf_InitCap(N'test STRING ß');
10+
11+
Source link: https://github.com/ktaranov/sqlserver-kit/blob/master/User_Defined_Function/dbo.udf_InitCap.sql
12+
Original link: https://gist.github.com/jef-sure/f67bc2c06c4804ca832f1dc5550c8db4
13+
Author: Anton Petrusevich
14+
Created Date: 2018-09-24
15+
Modified Date: 2019-07-23 by Konstantin Taranov
16+
*/
17+
RETURNS nvarchar(max) AS
18+
BEGIN
19+
DECLARE @StrNew nvarchar(max);
20+
DECLARE @c nvarchar(1);
21+
DECLARE @x integer;
22+
DECLARE @StrLen integer;
23+
DECLARE @CloseBracket nvarchar(5);
24+
DECLARE @OpenBracket varchar(5);
25+
DECLARE @mode varchar(20) = 'upper';
26+
SELECT @StrNew = '', @x = 1, @StrLen = LEN(@StrStr)+1;
27+
SELECT @OpenBracket = CHAR(34) + CHAR(39) + CHAR(40) + CHAR(91) + CHAR(123);
28+
SELECT @CloseBracket = CHAR(34) + CHAR(39) + CHAR(41) + CHAR(93) + CHAR(125);
29+
WHILE @x < @StrLen
30+
BEGIN
31+
SET @c = SUBSTRING(@StrStr, @x, 1);
32+
DECLARE @pbi INT;
33+
DECLARE @cb NCHAR(1);
34+
IF @c = 'ß' or unicode(LOWER(@c)) <> unicode(UPPER(@c))
35+
BEGIN
36+
IF @mode = 'lower'
37+
SET @c = lower(@c);
38+
IF @mode = 'upper'
39+
BEGIN
40+
SET @c = upper(@c);
41+
SET @mode = 'lower';
42+
END;
43+
END;
44+
ELSE
45+
BEGIN
46+
SET @pbi = CHARINDEX(@c, @OpenBracket);
47+
IF @pbi <> 0
48+
BEGIN
49+
SET @cb = SUBSTRING(@CloseBracket, @pbi, 1);
50+
SET @mode = 'preserve';
51+
END
52+
ELSE
53+
IF @mode <> 'preserve'
54+
SET @mode = 'upper';
55+
ELSE
56+
IF @c = @cb
57+
SET @mode = 'upper';
58+
END;
59+
SET @StrNew = @StrNew + @c;
60+
SET @x = @x +1;
61+
END;
62+
RETURN @StrNew;
63+
END;
64+
GO

User_Defined_Function/dbo.udf_LCS.sql

+116
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,116 @@
1+
IF OBJECT_ID('dbo.udf_LCS') IS NULL
2+
EXECUTE ('CREATE FUNCTION dbo.udf_LCS() RETURNS nvarchar(max) AS RETURN SELECT 1 AS A;');
3+
GO
4+
5+
6+
ALTER FUNCTION dbo.udf_LCS
7+
/**
8+
summary: >
9+
The longest common subsequence (LCS) problem is the problem of finding the
10+
longest subsequence common to all sequences in two sequences. It differs
11+
from problems of finding common substrings: unlike substrings, subsequences
12+
are not required to occupy consecutive positions within the original
13+
sequences. For example, the sequences "1234" and "1224533324" have an LCS of "1234"
14+
Author: Phil Factor
15+
Revision: 1.1
16+
Created Date: 2019-04-05
17+
Modified date: 2019-07-08 Konstantin Taranov
18+
Original link: https://www.red-gate.com/simple-talk/blogs/using-json-for-matrices-in-sql-server/
19+
example:
20+
code:
21+
SELECT dbo.udf_LCS ('1234', '1224533324');
22+
SELECT dbo.udf_LCS ('thisisatest', 'testing123testing');
23+
SELECT dbo.udf_LCS ( 'XMJYAUZ', 'MZJAWXU');
24+
SELECT dbo.udf_LCS ( 'beginning-middle-ending', 'beginning-diddle-dum-ending');
25+
returns: >
26+
the longest common subsequence as a string
27+
**/
28+
(@xString varchar(max), @yString varchar(max))
29+
RETURNS varchar(max)
30+
AS
31+
BEGIN
32+
33+
DECLARE @ii int = 1; --inner index
34+
DECLARE @jj int = 1; --next loop index
35+
DECLARE @West int; --array reference number to left
36+
DECLARE @NorthWest int; --array reference previous left
37+
DECLARE @North int; --array reference previous
38+
DECLARE @Max int; --holds the maximum of two values
39+
DECLARE @Current int; --current number of matches
40+
DECLARE @Matrix nvarchar(max);
41+
DECLARE @PreviousRow nvarchar(2000); -- the previous matrix row
42+
DECLARE @JSON nvarchar(4000); --json work variable
43+
DECLARE @Numbers TABLE (jj int);
44+
-- SQL Prompt formatting off
45+
46+
INSERT INTO @Numbers(jj) --this is designed for words of max 40 characters
47+
VALUES(1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14),(15),
48+
(16),(17),(18),(19),(20),(21),(22),(23),(24),(25),(26),(27),(28),
49+
(29),(30),(31),(32),(33),(34),(35),(36),(37),(38),(39),(40)
50+
-- SQL Prompt formatting on
51+
--the to start with, the first row is all zeros.
52+
SELECT @PreviousRow =
53+
N'[' + Replicate('0,', Len(@xString) + 1) + N'"'
54+
+ Substring(@yString, 1, 1) + N'"]';
55+
SELECT @Matrix = @PreviousRow;--add this to the matrix
56+
/* we now build the matrix in bottom up fashion. */
57+
WHILE (@ii <= Len(@yString))
58+
BEGIN
59+
SELECT @West = 0, @JSON = NULL;
60+
--now create a row in just one query
61+
SELECT @NorthWest =
62+
Json_Value(@PreviousRow, '$[' + Cast(jj - 1 AS varchar(5)) + ']'),
63+
@North =
64+
Json_Value(@PreviousRow, '$[' + Cast(jj AS varchar(5)) + ']'),
65+
@Max = CASE WHEN @West > @North THEN @West ELSE @North END,
66+
@Current =
67+
CASE WHEN Substring(@xString, jj, 1) = Substring(@yString, @ii, 1) THEN
68+
@NorthWest + 1 ELSE @Max END,
69+
@JSON =
70+
Coalesce(@JSON + ',', '[0,')
71+
+ Coalesce(Cast(@Current AS varchar(5)), 'null'), @West = @Current
72+
FROM @Numbers AS f
73+
WHERE f.jj <= Len(@xString);
74+
--and store the result as the previous row
75+
SELECT @PreviousRow =
76+
@JSON + N',"' + Substring(@yString, @ii, 1) + N'"]';
77+
--and add the reow to the matrix
78+
SELECT @Matrix = Coalesce(@Matrix + ',
79+
', '') + @PreviousRow, @ii = @ii + 1;
80+
END;
81+
--we add the boundong brackets.
82+
SELECT @Matrix = N'[' + @Matrix + N']';
83+
SELECT @ii = Len(@yString), @jj = Len(@xString);
84+
DECLARE @previousColScore INT, @PreviousRowScore INT, @Ychar NCHAR;
85+
DECLARE @Subsequence NVARCHAR(4000) = '';
86+
WHILE (@Current > 0)
87+
BEGIN
88+
SELECT @Ychar = Substring(@yString, @ii, 1);
89+
IF (@Ychar = Substring(@xString, @jj, 1))
90+
-- If current character in X[] and Y[] are same, then it is part of LCS
91+
SELECT @ii = @ii - 1, @jj = @jj - 1,
92+
@Subsequence = @Ychar + @Subsequence, @Current = @Current - 1;
93+
ELSE
94+
--If not same, then find the larger of two and traverse in that direction
95+
BEGIN
96+
--find out the two scores, one to the north and one to the west
97+
SELECT @PreviousRowScore =
98+
Json_Value(
99+
@Matrix,
100+
'strict $[' + Convert(varchar(5), @ii - 1) + ']['
101+
+ Convert(varchar(5), @jj) + ']'
102+
),
103+
@previousColScore =
104+
Json_Value(
105+
@Matrix,
106+
'strict $[' + Convert(varchar(5), @ii) + ']['
107+
+ Convert(varchar(5), @jj - 1) + ']'
108+
);
109+
--either go north or west
110+
IF @PreviousRowScore < @previousColScore SELECT @jj = @jj - 1;
111+
ELSE SELECT @ii = @ii - 1;
112+
END;
113+
END;
114+
RETURN @Subsequence;
115+
END;
116+
GO

0 commit comments

Comments
 (0)