Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
Author |
Topic |
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-11-12 : 20:47:09
|
[code]-- Prepare sample dataDECLARE @Sample TABLE (ID INT, NetworkIP VARCHAR(15), SubnetMask VARCHAR(15))INSERT @SampleSELECT 1, '192.168.1.0', '255.255.255.128' UNION ALLSELECT 2, '10.1.1.64', '255.255.255.240' UNION ALLSELECT 3, '172.16.11.0', '255.255.255.252'-- Show the expected outputSELECT ID, NetworkIP, SubnetMask, dbo.fnIsInRangeIP('192.168.1.5', NetworkIP, SubnetMask) AS IsInRangeFROM @Sample[/code]And here is the function code[code]CREATE FUNCTION dbo.fnIsInRangeIP( @IP VARCHAR(15), @NetIP VARCHAR(15), @MaskIP VARCHAR(15))RETURNS BITASBEGIN RETURN CASE WHEN CAST(PARSENAME(@IP, 4) AS TINYINT) & CAST(PARSENAME(@MaskIP, 4) AS TINYINT) = CAST(PARSENAME(@NetIP, 4) AS TINYINT) & CAST(PARSENAME(@MaskIP, 4) AS TINYINT) AND CAST(PARSENAME(@IP, 3) AS TINYINT) & CAST(PARSENAME(@MaskIP, 3) AS TINYINT) = CAST(PARSENAME(@NetIP, 3) AS TINYINT) & CAST(PARSENAME(@MaskIP, 3) AS TINYINT) AND CAST(PARSENAME(@IP, 2) AS TINYINT) & CAST(PARSENAME(@MaskIP, 2) AS TINYINT) = CAST(PARSENAME(@NetIP, 2) AS TINYINT) & CAST(PARSENAME(@MaskIP, 2) AS TINYINT) AND CAST(PARSENAME(@IP, 1) AS TINYINT) & CAST(PARSENAME(@MaskIP, 1) AS TINYINT) = CAST(PARSENAME(@NetIP, 1) AS TINYINT) & CAST(PARSENAME(@MaskIP, 1) AS TINYINT) THEN 1 ELSE 0 ENDEND[/code] E 12°55'05.25"N 56°04'39.16" |
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-11-12 : 22:05:16
|
[code]SELECT dbo.fnNetworkRangeLowestIP('192.168.1.5', '255.255.255.240')SELECT dbo.fnNetworkRangeHighestIP('192.168.1.5', '255.255.255.240')[/code]And the code for these[code]CREATE FUNCTION [dbo].[fnNetworkRangeLowestIP]( @NetworkIP VARCHAR(15), @SubnetMask VARCHAR(15))RETURNS VARCHAR(15)ASBEGIN RETURN CAST(CAST(PARSENAME(@NetworkIP, 4) AS TINYINT) & CAST(PARSENAME(@SubnetMask, 4) AS TINYINT) AS VARCHAR(3)) + '.' + CAST(CAST(PARSENAME(@NetworkIP, 3) AS TINYINT) & CAST(PARSENAME(@SubnetMask, 3) AS TINYINT) AS VARCHAR(3)) + '.' + CAST(CAST(PARSENAME(@NetworkIP, 2) AS TINYINT) & CAST(PARSENAME(@SubnetMask, 2) AS TINYINT) AS VARCHAR(3)) + '.' + CAST(CAST(PARSENAME(@NetworkIP, 1) AS TINYINT) & CAST(PARSENAME(@SubnetMask, 1) AS TINYINT) AS VARCHAR(3))ENDCREATE FUNCTION [dbo].[fnNetworkRangeHighestIP]( @NetworkIP VARCHAR(15), @SubnetMask VARCHAR(15))RETURNS VARCHAR(15)ASBEGIN RETURN CAST(CAST(PARSENAME(@NetworkIP, 4) AS TINYINT) | (CAST(PARSENAME(@SubnetMask, 4) AS TINYINT) ^ 0xFF) AS VARCHAR(3)) + '.' + CAST(CAST(PARSENAME(@NetworkIP, 3) AS TINYINT) | (CAST(PARSENAME(@SubnetMask, 3) AS TINYINT) ^ 0xFF) AS VARCHAR(3)) + '.' + CAST(CAST(PARSENAME(@NetworkIP, 2) AS TINYINT) | (CAST(PARSENAME(@SubnetMask, 2) AS TINYINT) ^ 0xFF) AS VARCHAR(3)) + '.' + CAST(CAST(PARSENAME(@NetworkIP, 1) AS TINYINT) | (CAST(PARSENAME(@SubnetMask, 1) AS TINYINT) ^ 0xFF) AS VARCHAR(3))END[/code] E 12°55'05.25"N 56°04'39.16" |
|
|
|
|
|
|
|