Re: A question on using CIDR datatype for both ipv6 and ipv4 address

Lists: pgsql-admin
From: Dhaval Shah <dhaval(dot)shah(dot)m(at)gmail(dot)com>
To: pgsql-admin(at)postgresql(dot)org
Subject: A question on using CIDR datatype for both ipv6 and ipv4 address
Date: 2011-07-28 23:29:28
Message-ID: CAPGmB+DJqovfoDFnCaZ+2FSOVZDpYWJTbXPev4reKck2+2EhCg@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-admin

I need some help in understanding why this is not working:

I have created a cidr_test table with datatypes cidr, varchar and bigint.,

rwdb=# \d cidr_test;
Table "public.cidr_test"
Column | Type | Modifiers
--------------+-----------------------+-----------
ip_as_cidr | cidr |
ip_as_text | character varying(40) |
ip_as_number | bigint |

And populated the table with the following values:

rwdb=# select * from cidr_test;
ip_as_cidr | ip_as_text | ip_as_number
------------------------+--------------------+--------------
::ffff:192.0.2.128/128 | ::ffff:192.0.2.128 | 3221226112
::ffff:192.0.2.125/128 | ::ffff:192.0.2.125 | 3221226109
::ffff:192.0.2.126/128 | ::ffff:192.0.2.126 | 3221226110
::ffff:192.0.2.127/128 | ::ffff:192.0.2.127 | 3221226111
192.0.2.124/32 | 192.0.2.124 | 3221226108
(5 rows)

Note that the 5th row, is an IPV4 address in IPV4 format unlike others
which are in IPV6 format.

When I run the following query:

select * from cidr_test where inet(ip_as_cidr) >= inet '::ffff:192.0.2.124/128';

ip_as_cidr | ip_as_text | ip_as_number
------------------------+--------------------+--------------
::ffff:192.0.2.128/128 | ::ffff:192.0.2.128 | 3221226112
::ffff:192.0.2.125/128 | ::ffff:192.0.2.125 | 3221226109
::ffff:192.0.2.126/128 | ::ffff:192.0.2.126 | 3221226110
::ffff:192.0.2.127/128 | ::ffff:192.0.2.127 | 3221226111
(4 rows)

The results are different from the following:

select * from cidr_test where inet(ip_as_cidr) >= inet '192.0.2.124/32';

ip_as_cidr | ip_as_text | ip_as_number
------------------------+--------------------+--------------
::ffff:192.0.2.128/128 | ::ffff:192.0.2.128 | 3221226112
::ffff:192.0.2.125/128 | ::ffff:192.0.2.125 | 3221226109
::ffff:192.0.2.126/128 | ::ffff:192.0.2.126 | 3221226110
::ffff:192.0.2.127/128 | ::ffff:192.0.2.127 | 3221226111
192.0.2.124/32 | 192.0.2.124 | 3221226108
(5 rows)

Let me know why I am not getting similar results when the RHS is an
IPV4 in IPV6 format vs, the RHS in IPV4 format.

Thanks in advance!


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Dhaval Shah <dhaval(dot)shah(dot)m(at)gmail(dot)com>
Cc: pgsql-admin(at)postgresql(dot)org
Subject: Re: A question on using CIDR datatype for both ipv6 and ipv4 address
Date: 2011-07-28 23:58:01
Message-ID: 9134.1311897481@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-admin

Dhaval Shah <dhaval(dot)shah(dot)m(at)gmail(dot)com> writes:
> Let me know why I am not getting similar results when the RHS is an
> IPV4 in IPV6 format vs, the RHS in IPV4 format.

AFAIR, the inet/cidr types consider IPv4 to be an independent set of
values that sort in front of all IPv6 values. The notion that IPv4
might be embedded in some part of the IPv6 space is not something that
that code is aware of. If it did try to do that, you'd have
'::ffff:192.0.2.124' comparing as equal to '192.0.2.124', which would
be okay for some purposes but not all.

regards, tom lane