Systems Engineering and RDBMS

  • Click Here for Decipher's Homepage


  • Categories

  • Questions?

    Please send your wish list of things that you would like us to write about or if you have suggestions to help improve this blog site. You can send all questions/suggestions to: Blog Support
  • Archives

  • Blog Stats

    • 7,609,421 Views

Archive for December 28th, 2007

Sorting IP Addresses

Posted by decipherinfosys on December 28, 2007

This is a simple but interesting issue. One of the IT guys at our client sites had asked the client DBA to provide him with the name of the servers, their domain and other bits of information sorted by the IP addresses. Now, IP addresses are represented in dotted decimal notation i.e. four numbers, each ranging from 0 to 255 and separated by dots. Each range from 0 to 255 can be represented by 8 bits and is thus called an octet. Some first octet values like 127 have special meaning – 127 represents the local computer. Octets 0 and 255 are not acceptable values in some situations. 0 can however be used as the second and third octet.

So, as you can imagine that unless we are storing the data in a sortable friendly way, sorting of this data would require some string manipulation. Let’s follow this up with an example:

CREATE TABLE IP_ADDR (COL1 NVARCHAR(30));
INSERT INTO IP_ADDR VALUES ( ‘30.33.33.30’ );
INSERT INTO IP_ADDR VALUES ( ‘256.10.1.2’ );
INSERT INTO IP_ADDR VALUES ( ‘256.255.10.2’ );
INSERT INTO IP_ADDR VALUES ( ‘127.0.0.1’ );
INSERT INTO IP_ADDR VALUES ( ‘132.22.33.44’ );
INSERT INTO IP_ADDR VALUES ( ‘132.10.30.1’ );
INSERT INTO IP_ADDR VALUES ( ‘132.1.1.132’ );
INSERT INTO IP_ADDR VALUES ( ‘10.20.30.10’ );
Now, if we order by COL1, then we will get:

SELECT * FROM IP_ADDR ORDER BY COL1;

COL1
——————————
10.20.30.10
127.0.0.1
132.1.1.132
132.10.30.1
132.22.33.44
256.10.1.2
256.255.10.2
30.33.33.30

As you can see from above, 30.33.33.30 comes last though we should expect it after 10.20.30.10. And likewise, in some other cases as well. Now, if we use the SUBSTRING (SQL Server) – SUBSTR in Oracle function and make use of the CHARINDEX (SQL Server) or INSTR (Oracle) or LOCATE (DB2 LUW), we can easily do these manipulations. Let us take SQL Server as an example – the same methodology would apply to Oracle and DB2 as well but do keep in mind the differences between CHARINDEX(), INSTR() and LOCATE() – we had discussed these before in some of our blog posts.

SELECT 
SUBSTRING(COL1, 1, CHARINDEX('.', COL1) - 1) AS FIRST_OCTET, 
CAST(SUBSTRING(COL1, CHARINDEX('.', COL1)+1, CHARINDEX('.', SUBSTRING(COL1, CHARINDEX('.', COL1)+1, LEN(COL1))) - 1) AS INT) AS SECOND_OCTET,
*
    FROM IP_ADDR 
        ORDER BY 
            CAST(SUBSTRING(COL1, 1, CHARINDEX('.', COL1) - 1) AS INT),
            CAST(SUBSTRING(COL1, CHARINDEX('.', COL1)+1, CHARINDEX('.', SUBSTRING(COL1, CHARINDEX('.', COL1)+1, LEN(COL1))) - 1) AS INT)

The SQL above is used to show how to use the CHARINDEX() and the SUBSTRING() function to separate out the first and the second octets…you can do the same with the third and the fourth one as well and then order by on those in the same order i.e. the first_octet first (after converting it to an integer), then the second_octet and so on.  Here are the results from the execution from above:

FIRST_OCTET                    SECOND_OCTET COL1
------------------------------ ------------ ------------------------------
10                             20           10.20.30.10
30                             33           30.33.33.30
127                            0            127.0.0.1
132                            1            132.1.1.132
132                            10           132.10.30.1
132                            22           132.22.33.44
256                            10           256.10.1.2
256                            255          256.255.10.2

Posted in DB2 LUW, Oracle, SQL Server | Leave a Comment »