Skip to content

Commit 8f05c67

Browse files
committed
Initial inet data type implementation
1 parent fe112d6 commit 8f05c67

File tree

30 files changed

+14944
-58
lines changed

30 files changed

+14944
-58
lines changed

Makefile

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -23,7 +23,7 @@ GISTEST=nogis
2323
endif
2424

2525
ifndef REGRESS
26-
REGRESS = extra/sqlite_fdw_post types/bitstring types/bool types/float4 types/float8 types/int4 types/int8 types/numeric types/$(GISTEST) types/macaddr types/macaddr8 types/out_of_range types/timestamp types/uuid extra/join extra/limit extra/aggregates extra/prepare extra/select_having extra/select extra/insert extra/update extra/encodings sqlite_fdw type_$(GISTEST) aggregate selectfunc
26+
REGRESS = extra/sqlite_fdw_post types/bitstring types/bool types/float4 types/float8 types/inet types/int4 types/int8 types/numeric types/$(GISTEST) types/macaddr types/macaddr8 types/out_of_range types/timestamp types/uuid extra/join extra/limit extra/aggregates extra/prepare extra/select_having extra/select extra/insert extra/update extra/encodings sqlite_fdw type_$(GISTEST) aggregate selectfunc
2727
endif
2828

2929
REGRESS_OPTS = --encoding=utf8

README.md

Lines changed: 109 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -48,18 +48,20 @@ Features
4848
- `bool`: `text`(1..5) and `int`,
4949
- `double precision`, `float` and `numeric`: `real` values and special values with `text` affinity (`+Infinity`, `-Infinity`, `NaN`),
5050
- `macaddr`: `text`(12..17) or `blob`(6) or `integer`,
51-
- `macaddr8`: `text`(16..23) or `blob`(8) or `integer`.
51+
- `macaddr8`: `text`(16..23) or `blob`(8) or `integer`,
52+
- `inet`: `text`(8..49) or `blob`(4..5 IP v4, 16..17 IP v6) or `integer` (IP v4).
5253
- Support mixed SQLite [data affinity](https://www.sqlite.org/datatype3.html) output (`INSERT`/`UPDATE`) for such data types as
5354
- `timestamp`: `text`(default) or `int`,
5455
- `uuid`: `text`(36) or `blob`(16)(default),
5556
- `macaddr`: `text`(17) or `blob`(6) or `integer`(default),
56-
- `macaddr8`: `text`(23) or `blob`(8) or `integer`(default).
57+
- `macaddr8`: `text`(23) or `blob`(8) or `integer`(default),
58+
- `inet`: `integer` (default for IP v4) or `blob`(4..5 IP v4, 16..17 default for IP v6) or `text`(8..49).
5759
- Full support for `+Infinity` (means ∞) and `-Infinity` (means -∞) special values for IEEE 754-2008 numbers in `double precision`, `float` and `numeric` columns including such conditions as ` n < '+Infinity'` or ` m > '-Infinity'`.
5860
- Bidirectional data transformation for `geometry` and `geography` data types for SpatiaLite ↔ PostGIS. [EWKB](https://libgeos.org/specifications/wkb/#extended-wkb) data transport is used. See [GIS support description](GIS.md).
5961

6062
### Pushing down
6163
- `WHERE` clauses are pushdowned
62-
- Aggregate function are pushdowned
64+
- Aggregate functions are pushdowned
6365
- `ORDER BY` is pushdowned
6466
- Joins (left/right/inner/cross/semi) are pushdowned
6567
- `CASE` expressions are pushdowned.
@@ -254,6 +256,7 @@ SQLite `NULL` affinity always can be transparent converted for a nullable column
254256
| float8 | V+ ||| i | `NULL` | REAL |
255257
|[geometry](GIS.md)||| V+ ||| BLOB |
256258
|[geography](GIS.md)||| V+ ||| BLOB |
259+
| inet | ✔- ||V<br>(Len=4..5, 16..17)| V+ | `NULL` | INT v4, BLOB v6 |
257260
| int2 | ✔- | ? ||| `NULL` | INT |
258261
| int4 | ✔- | ? ||| `NULL` | INT |
259262
| int8 || ? ||| `NULL` | INT |
@@ -625,6 +628,17 @@ Array support is experimental. Please be careful.
625628
- `sqlite_fdw` UUID values support exists only for `uuid` columns in foreign table. SQLite documentation recommends to store UUID as value with both `blob` and `text` [affinity](https://www.sqlite.org/datatype3.html). `sqlite_fdw` can pushdown both reading and filtering both `text` and `blob` values.
626629
- Expected affinity of UUID value in SQLite table determined by `column_type` option of the column
627630
for `INSERT` and `UPDATE` commands. PostgreSQL supports both `blob` and `text` [affinity](https://www.sqlite.org/datatype3.html).
631+
- Usual form of UUID from a value with `blob` affinity can be generated with such SQLite query as
632+
```sql
633+
select case when typeof(u) = 'blob' then
634+
substr(lower(hex(u)),1,8) || '-' ||
635+
substr(lower(hex(u)),9,4) || '-' ||
636+
substr(lower(hex(u)),13,4) || '-' ||
637+
substr(lower(hex(u)),17,4) || '-' ||
638+
substr(lower(hex(u)),21,12)
639+
else null end uuid_canon
640+
from "type_UUID";
641+
```
628642

629643
### bit and varbit support
630644
- `sqlite_fdw` PostgreSQL `bit`/`varbit` values support based on `int` SQLite data affinity, because there is no per bit operations for SQLite `blob` affinity data. Maximum SQLite `int` affinity value is 8 bytes length, hence maximum `bit`/`varbit` values length is 64 bits.
@@ -633,6 +647,98 @@ for `INSERT` and `UPDATE` commands. PostgreSQL supports both `blob` and `text` [
633647
### MAC address support
634648
- `sqlite_fdw` PostgreSQL `macaddr`/`macaddr8` values support based on `int` SQLite data affinity, because there is no per bit operations for SQLite `blob` affinity data. For `macaddr` out of range error is possible because this type is 6 bytes length, but SQLite `int` can store value up to 8 bytes.
635649
- `sqlite_fdw` doesn't pushdown any operations with MAC adresses because there is 3 possible affinities for it in SQLite: `integer`, `blob` and `text`.
650+
### IP address support
651+
- `sqlite_fdw` PostgreSQL `inet` values support based on `int` SQLite data affinity for IP v4 and `blob` SQLite data affinity for IP v6.
652+
- Usual form of IP v4 address with cidr from a value with `integer` affinity can be generated with such SQLite query as
653+
```sql
654+
select case when typeof(ip) = 'integer'
655+
then ((ip >> 24) & 255) || '.' || ((ip >> 16) & 255) || '.' || ((ip >> 8) & 255) || '.' || (ip & 255) ||
656+
case when (ip >> 32) > 0 then '/' || (ip >> 32) else '' end
657+
else null
658+
end ipv4_text,
659+
ip
660+
from "type_INET";
661+
```
662+
- Usual form of IP v6 or IP v4 address from a value with `blob` affinity can be generated with such SQLite query as
663+
```sql
664+
select
665+
case
666+
when typeof(ip) = 'blob' and (length(ip) = 16 or length(ip) = 17) then
667+
lower(
668+
substr(hex(ip),1,4) || ':' ||
669+
substr(hex(ip),5,4) || ':' ||
670+
substr(hex(ip),9,4) || ':' ||
671+
substr(hex(ip),13,4) || ':' ||
672+
substr(hex(ip),17,4) || ':' ||
673+
substr(hex(ip),21,4) || ':' ||
674+
substr(hex(ip),25,4) || ':' ||
675+
substr(hex(ip),29,4)
676+
) ||
677+
case
678+
when length(ip) = 17 then
679+
'/' || ((instr('123456789ABCDEF', substr(hex(ip),33,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),34,1)))
680+
else ''
681+
end
682+
when typeof(ip) = 'blob' and (length(ip) = 4 or length(ip) = 5) then
683+
((instr('123456789ABCDEF', substr(hex(ip),1,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),2,1))) || '.' ||
684+
((instr('123456789ABCDEF', substr(hex(ip),3,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),4,1))) || '.' ||
685+
((instr('123456789ABCDEF', substr(hex(ip),5,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),6,1))) || '.' ||
686+
((instr('123456789ABCDEF', substr(hex(ip),7,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),8,1)))
687+
||
688+
case
689+
when length(ip) = 5 then
690+
'/' || ((instr('123456789ABCDEF', substr(hex(ip),9,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),10,1)))
691+
else ''
692+
end
693+
else null
694+
end as ip_text
695+
from "type_INET";
696+
```
697+
- IP address with possible cidr addition enconing as SQLite BLOB value based on such conventions
698+
```
699+
m - mask as number of bits
700+
a - bytes of IP address
701+
702+
IP v4 + cidr
703+
┏━━━┳━━━┳━━━┳━━━┳━━━┓
704+
┃ a ┃ a ┃ a ┃ a ┃ m ┃
705+
┗━━━┻━━━┻━━━┻━━━┻━━━┛
706+
0 1 2 3 4 - byte index
707+
IP v6 + cidr
708+
┏━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┓
709+
┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ m ┃
710+
┗━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┛
711+
0 1 2 3 4 5 5 7 8 9 10 11 12 13 14 15 16 17 - byte index
712+
713+
IP v4
714+
┏━━━┳━━━┳━━━┳━━━┓
715+
┃ a ┃ a ┃ a ┃ a ┃
716+
┗━━━┻━━━┻━━━┻━━━┛
717+
0 1 2 3 - byte index
718+
IP v6
719+
┏━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┓
720+
┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃
721+
┗━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┛
722+
0 1 2 3 4 5 5 7 8 9 10 11 12 13 14 15 16 - byte index
723+
```
724+
- IP address v4 with possible cidr addition enconing as SQLite integer based on such conventions
725+
```
726+
m - mask as number of bits
727+
a - IP address bytes
728+
729+
IP v4 + cidr
730+
┏━━━┳━━━┳━━━┳━━━┳━━━┓
731+
┃ m ┃ a ┃ a ┃ a ┃ a ┃
732+
┗━━━┻━━━┻━━━┻━━━┻━━━┛
733+
0 1 2 3 4 - byte index
734+
735+
IP v4
736+
┏━━━┳━━━┳━━━┳━━━┓
737+
┃ a ┃ a ┃ a ┃ a ┃
738+
┗━━━┻━━━┻━━━┻━━━┛
739+
0 1 2 3 - byte index
740+
```
741+
- `sqlite_fdw` doesn't pushdown any operations with IP adresses because there is 3 possible affinities for it in SQLite: `integer`, `blob` and `text`.
636742

637743
Tests
638744
-----

deparse.c

Lines changed: 72 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -33,9 +33,11 @@
3333
#include "parser/parsetree.h"
3434
#include "parser/parse_type.h"
3535
#include "utils/builtins.h"
36+
#include "utils/inet.h"
3637
#include "utils/lsyscache.h"
3738
#include "utils/syscache.h"
3839
#include "utils/typcache.h"
40+
#include <sys/socket.h>
3941

4042
/*
4143
* Global context for sqlite_foreign_expr_walker's search of an expression tree.
@@ -362,6 +364,7 @@ sqlite_deparsable_data_type(Param *p)
362364
case UUIDOID:
363365
case MACADDROID:
364366
case MACADDR8OID:
367+
case INETOID:
365368
return true;
366369
}
367370
#ifdef SQLITE_FDW_GIS_ENABLE
@@ -2373,6 +2376,16 @@ sqlite_deparse_column_ref(StringInfo buf, int varno, int varattno, PlannerInfo *
23732376
appendStringInfo(buf, ", %d)", mac_len);
23742377
break;
23752378
}
2379+
case INETOID:
2380+
{
2381+
elog(DEBUG2, "IP addr unification for \"%s\"", colname);
2382+
appendStringInfoString(buf, "sqlite_fdw_ipaddr_blob(");
2383+
if (qualify_col)
2384+
ADD_REL_QUALIFIER(buf, varno);
2385+
appendStringInfoString(buf, sqlite_quote_identifier(colname, '`'));
2386+
appendStringInfoString(buf, ")");
2387+
break;
2388+
}
23762389
default:
23772390
{
23782391
no_unification = true;
@@ -2736,6 +2749,24 @@ sqlite_deparse_direct_update_sql(StringInfo buf, PlannerInfo *root,
27362749
appendStringInfo(buf, "sqlite_fdw_macaddr_blob(");
27372750
special_affinity = true;
27382751
}
2752+
else if (pg_attyp == INETOID)
2753+
{
2754+
if (preferred_affinity == SQLITE_TEXT)
2755+
{
2756+
appendStringInfo(buf, "sqlite_fdw_ipaddr_str(");
2757+
special_affinity = true;
2758+
}
2759+
else if (preferred_affinity == SQLITE_INTEGER)
2760+
{
2761+
appendStringInfo(buf, "sqlite_fdw_ipaddr_int(");
2762+
special_affinity = true;
2763+
}
2764+
else if (preferred_affinity == SQLITE_NULL)
2765+
{
2766+
appendStringInfo(buf, "sqlite_fdw_ipaddr_native(");
2767+
special_affinity = true;
2768+
}
2769+
}
27392770

27402771
sqlite_deparse_expr((Expr *) tle->expr, &context);
27412772

@@ -2996,6 +3027,22 @@ sqlite_deparse_const(Const *node, deparse_expr_cxt *context, int showtype)
29963027

29973028
switch (node->consttype)
29983029
{
3030+
/* Common cases are first as very frequent */
3031+
case BPCHAROID:
3032+
case VARCHAROID:
3033+
case CHAROID:
3034+
case TEXTOID:
3035+
case JSONOID:
3036+
case JSONBOID:
3037+
case NAMEOID:
3038+
case DATEOID:
3039+
case TIMEOID:
3040+
{
3041+
/* common branch of constants, deparsable as a text data */
3042+
extval = OidOutputFunctionCall(typoutput, node->constvalue);
3043+
sqlite_deparse_string_literal(buf, extval);
3044+
break;
3045+
}
29993046
case INT2OID:
30003047
case INT4OID:
30013048
case INT8OID:
@@ -3143,21 +3190,33 @@ sqlite_deparse_const(Const *node, deparse_expr_cxt *context, int showtype)
31433190
}
31443191
}
31453192
break;
3146-
case BPCHAROID:
3147-
case VARCHAROID:
3148-
case CHAROID:
3149-
case TEXTOID:
3150-
case JSONOID:
3151-
case JSONBOID:
3152-
case NAMEOID:
3153-
case DATEOID:
3154-
case TIMEOID:
3193+
case INETOID:
31553194
{
3156-
/* common branch of constants, deparsable as a text data */
3157-
extval = OidOutputFunctionCall(typoutput, node->constvalue);
3158-
sqlite_deparse_string_literal(buf, extval);
3159-
break;
3195+
inet *pg_inet = DatumGetInetP(node->constvalue);
3196+
unsigned char bits = ip_bits(pg_inet);
3197+
unsigned char *ipaddr = pg_inet->inet_data.ipaddr;
3198+
3199+
appendStringInfo(buf, "X\'");
3200+
for (int i = 0; i < ip_addrsize(pg_inet); i++)
3201+
{
3202+
int d1 = (ipaddr[i] >> 4) & 0x0F;
3203+
int d2 = ipaddr[i] & 0x0F;
3204+
3205+
appendStringInfoChar(buf, hex_dig[d1]);
3206+
appendStringInfoChar(buf, hex_dig[d2]);
3207+
}
3208+
/* Is here an address mask? */
3209+
if (bits < ip_maxbits(pg_inet))
3210+
{
3211+
int d1 = (bits >> 4) & 0x0F;
3212+
int d2 = bits & 0x0F;
3213+
3214+
appendStringInfoChar(buf, hex_dig[d1]);
3215+
appendStringInfoChar(buf, hex_dig[d2]);
3216+
}
3217+
appendStringInfo(buf, "\'");
31603218
}
3219+
break;
31613220
default:
31623221
{
31633222
if (listed_datatype_oid(node->consttype, -1, postGisSQLiteCompatibleTypes))

expected/13.15/type_nogis.out

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -533,7 +533,7 @@ SELECT * FROM "type_DOUBLE"; -- OK, +- Inf
533533

534534
--Testcase 47:
535535
DROP EXTENSION sqlite_fdw CASCADE;
536-
NOTICE: drop cascades to 55 other objects
536+
NOTICE: drop cascades to 57 other objects
537537
DETAIL: drop cascades to server sqlite_svr
538538
drop cascades to foreign table department
539539
drop cascades to foreign table employee
@@ -567,6 +567,8 @@ drop cascades to foreign table "type_MACADDRpk"
567567
drop cascades to foreign table "type_MACADDR"
568568
drop cascades to foreign table "type_MACADDR8pk"
569569
drop cascades to foreign table "type_MACADDR8"
570+
drop cascades to foreign table "type_INETpk"
571+
drop cascades to foreign table "type_INET"
570572
drop cascades to foreign table "types_PostGIS"
571573
drop cascades to foreign table "BitT"
572574
drop cascades to foreign table notype

expected/13.15/type_postgis.out

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -535,7 +535,7 @@ SELECT * FROM "type_DOUBLE"; -- OK, +- Inf
535535

536536
--Testcase 47:
537537
DROP EXTENSION sqlite_fdw CASCADE;
538-
NOTICE: drop cascades to 55 other objects
538+
NOTICE: drop cascades to 57 other objects
539539
DETAIL: drop cascades to server sqlite_svr
540540
drop cascades to foreign table department
541541
drop cascades to foreign table employee
@@ -569,6 +569,8 @@ drop cascades to foreign table "type_MACADDRpk"
569569
drop cascades to foreign table "type_MACADDR"
570570
drop cascades to foreign table "type_MACADDR8pk"
571571
drop cascades to foreign table "type_MACADDR8"
572+
drop cascades to foreign table "type_INETpk"
573+
drop cascades to foreign table "type_INET"
572574
drop cascades to foreign table "types_PostGIS"
573575
drop cascades to foreign table "BitT"
574576
drop cascades to foreign table notype

0 commit comments

Comments
 (0)