Skip to content

Instantly share code, notes, and snippets.

@zzzeek
Last active March 10, 2017 01:03
Show Gist options
  • Star 1 You must be signed in to star a gist
  • Fork 2 You must be signed in to fork a gist
  • Save zzzeek/3cf63d88dbc5246dcfafe9828ab92e3e to your computer and use it in GitHub Desktop.
Save zzzeek/3cf63d88dbc5246dcfafe9828ab92e3e to your computer and use it in GitHub Desktop.
detect overlapping CIDR ranges in SQL, prevent duplicate ranges using triggers
from sqlalchemy import event
from sqlalchemy import DDL
def mysql_cidr_overlap(engine, metadata):
@event.listens_for(metadata, "after_create")
def _create_mysql_proc(target, connection, **kw):
if connection.engine.name != 'mysql':
return
if connection.scalar(
"SELECT ROUTINE_NAME FROM INFORMATION_SCHEMA.ROUTINES "
"WHERE ROUTINE_TYPE='FUNCTION' AND ROUTINE_SCHEMA=DATABASE() AND "
"ROUTINE_NAME=%s",
("cidr_overlap", )
):
connection.execute("DROP FUNCTION cidr_overlap")
connection.execute(
DDL("""
CREATE FUNCTION cidr_overlap (cidr1 VARCHAR(30), cidr2 VARCHAR(30))
RETURNS TINYINT
BEGIN
DECLARE bitmask INT;
-- note - Mike is semi-guessing on the math here, needs tests! don't stick
-- into production pls :)
SET bitmask = pow(
2,
(32 - least(
cast(substring_index(cidr1, '/', -1) as integer),
cast(substring_index(cidr2, '/', -1) as integer)
))
) - 1;
RETURN
inet_aton(substring_index(cidr1, '/', 1)) & ~bitmask =
inet_aton(substring_index(cidr2, '/', 1)) & ~bitmask;
END
""")
)
if __name__ == '__main__':
from sqlalchemy import Column, Integer, String, create_engine, func
from sqlalchemy.ext.declarative import declarative_base
from sqlalchemy.orm import Session, aliased
from sqlalchemy import event
Base = declarative_base()
class A(Base):
__tablename__ = 'a'
id = Column(Integer, primary_key=True)
subnet = Column(String(30))
event.listen(
A.__table__, "after_create",
DDL("""
CREATE TRIGGER no_overlap_cidr_a
BEFORE INSERT ON a
FOR EACH ROW
BEGIN
DECLARE msg VARCHAR(200);
IF (EXISTS(SELECT * FROM a WHERE cidr_overlap(subnet, NEW.subnet))) THEN
SET msg = CONCAT(
'inserted subnet ', NEW.subnet,
' conflicts with existing subnets');
SIGNAL sqlstate '45000'
SET MESSAGE_TEXT = msg;
END IF;
END
""")
)
e = create_engine("mysql://scott:tiger@localhost/test", echo=True)
mysql_cidr_overlap(e, Base.metadata)
Base.metadata.drop_all(e)
Base.metadata.create_all(e)
s = Session(e)
with s.begin_nested():
s.add(A(subnet='192.168.1.0/24'))
with s.begin_nested():
s.add(A(subnet='192.168.2.0/24'))
try:
with s.begin_nested():
s.add(A(subnet='192.168.2.0/25'))
except Exception as e:
print "Error! %s" % e
s.commit()
a1, a2 = aliased(A), aliased(A)
# return all non-overlapping CIDR pairs
for a, b in s.query(a1.subnet, a2.subnet).\
filter(~func.cidr_overlap(a1.subnet, a2.subnet)).\
filter(a1.id > a2.id):
print a, b
@zzzeek
Copy link
Author

zzzeek commented May 6, 2016

Here's the output:

2016-05-06 10:29:30,939 INFO sqlalchemy.engine.base.Engine SHOW VARIABLES LIKE 'sql_mode'
2016-05-06 10:29:30,939 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,941 INFO sqlalchemy.engine.base.Engine SELECT DATABASE()
2016-05-06 10:29:30,941 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,941 INFO sqlalchemy.engine.base.Engine show collation where `Charset` = 'utf8' and `Collation` = 'utf8_bin'
2016-05-06 10:29:30,941 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,943 INFO sqlalchemy.engine.base.Engine SELECT CAST('test plain returns' AS CHAR(60)) AS anon_1
2016-05-06 10:29:30,944 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,945 INFO sqlalchemy.engine.base.Engine SELECT CAST('test unicode returns' AS CHAR(60)) AS anon_1
2016-05-06 10:29:30,945 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,945 INFO sqlalchemy.engine.base.Engine SELECT CAST('test collated returns' AS CHAR CHARACTER SET utf8) COLLATE utf8_bin AS anon_1
2016-05-06 10:29:30,946 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,947 INFO sqlalchemy.engine.base.Engine DESCRIBE `a`
2016-05-06 10:29:30,947 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,948 INFO sqlalchemy.engine.base.Engine 
DROP TABLE a
2016-05-06 10:29:30,949 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,958 INFO sqlalchemy.engine.base.Engine COMMIT
2016-05-06 10:29:30,959 INFO sqlalchemy.engine.base.Engine DESCRIBE `a`
2016-05-06 10:29:30,959 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,960 INFO sqlalchemy.engine.base.Engine ROLLBACK
2016-05-06 10:29:30,961 INFO sqlalchemy.engine.base.Engine 
CREATE TABLE a (
    id INTEGER NOT NULL AUTO_INCREMENT, 
    subnet VARCHAR(30), 
    PRIMARY KEY (id)
)


2016-05-06 10:29:30,962 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,985 INFO sqlalchemy.engine.base.Engine COMMIT
2016-05-06 10:29:30,986 INFO sqlalchemy.engine.base.Engine 
    CREATE TRIGGER no_overlap_cidr_a
    BEFORE INSERT ON a
    FOR EACH ROW
    BEGIN
      DECLARE msg VARCHAR(200);
      IF (EXISTS(SELECT * FROM a WHERE cidr_overlap(subnet, NEW.subnet))) THEN
        SET msg = CONCAT(
            'inserted subnet ', NEW.subnet,
            ' conflicts with existing subnets');
        SIGNAL sqlstate '45000'
            SET MESSAGE_TEXT = msg;
      END IF;
    END

2016-05-06 10:29:30,986 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,993 INFO sqlalchemy.engine.base.Engine COMMIT
2016-05-06 10:29:30,994 INFO sqlalchemy.engine.base.Engine SELECT ROUTINE_NAME FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_TYPE='FUNCTION' AND ROUTINE_SCHEMA=DATABASE() AND ROUTINE_NAME=%s
2016-05-06 10:29:30,994 INFO sqlalchemy.engine.base.Engine ('cidr_overlap',)
2016-05-06 10:29:30,995 INFO sqlalchemy.engine.base.Engine DROP FUNCTION cidr_overlap
2016-05-06 10:29:30,995 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:30,998 INFO sqlalchemy.engine.base.Engine COMMIT
2016-05-06 10:29:30,999 INFO sqlalchemy.engine.base.Engine 
        CREATE FUNCTION cidr_overlap (cidr1 VARCHAR(30), cidr2 VARCHAR(30))
        RETURNS TINYINT
        BEGIN
        DECLARE bitmask INT;
        -- note - Mike is semi-guessing on the math here, needs tests!  don't stick
        -- into production pls :)
        SET bitmask = pow(
            2,
            (32 - least(
                cast(substring_index(cidr1, '/', -1) as integer),
                cast(substring_index(cidr2, '/', -1) as integer)
            ))
        ) - 1;

        RETURN
            inet_aton(substring_index(cidr1, '/', 1)) & ~bitmask =
            inet_aton(substring_index(cidr2, '/', 1)) & ~bitmask;
        END

2016-05-06 10:29:30,999 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:31,003 INFO sqlalchemy.engine.base.Engine COMMIT
2016-05-06 10:29:31,005 INFO sqlalchemy.engine.base.Engine BEGIN (implicit)
2016-05-06 10:29:31,005 INFO sqlalchemy.engine.base.Engine SAVEPOINT sa_savepoint_1
2016-05-06 10:29:31,005 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:31,006 INFO sqlalchemy.engine.base.Engine INSERT INTO a (subnet) VALUES (%s)
2016-05-06 10:29:31,006 INFO sqlalchemy.engine.base.Engine ('192.168.1.0/24',)
2016-05-06 10:29:31,008 INFO sqlalchemy.engine.base.Engine RELEASE SAVEPOINT sa_savepoint_1
2016-05-06 10:29:31,008 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:31,009 INFO sqlalchemy.engine.base.Engine SAVEPOINT sa_savepoint_2
2016-05-06 10:29:31,009 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:31,010 INFO sqlalchemy.engine.base.Engine INSERT INTO a (subnet) VALUES (%s)
2016-05-06 10:29:31,010 INFO sqlalchemy.engine.base.Engine ('192.168.2.0/24',)
2016-05-06 10:29:31,011 INFO sqlalchemy.engine.base.Engine RELEASE SAVEPOINT sa_savepoint_2
2016-05-06 10:29:31,012 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:31,013 INFO sqlalchemy.engine.base.Engine SAVEPOINT sa_savepoint_3
2016-05-06 10:29:31,013 INFO sqlalchemy.engine.base.Engine ()
2016-05-06 10:29:31,013 INFO sqlalchemy.engine.base.Engine INSERT INTO a (subnet) VALUES (%s)
2016-05-06 10:29:31,014 INFO sqlalchemy.engine.base.Engine ('192.168.2.0/25',)
2016-05-06 10:29:31,015 INFO sqlalchemy.engine.base.Engine ROLLBACK TO SAVEPOINT sa_savepoint_3
2016-05-06 10:29:31,015 INFO sqlalchemy.engine.base.Engine ()
Error! (_mysql_exceptions.OperationalError) (1644, 'inserted subnet 192.168.2.0/25 conflicts with existing subnets') [SQL: u'INSERT INTO a (subnet) VALUES (%s)'] [parameters: ('192.168.2.0/25',)]
2016-05-06 10:29:31,015 INFO sqlalchemy.engine.base.Engine COMMIT
2016-05-06 10:29:31,021 INFO sqlalchemy.engine.base.Engine BEGIN (implicit)
2016-05-06 10:29:31,022 INFO sqlalchemy.engine.base.Engine SELECT a_1.subnet AS a_1_subnet, a_2.subnet AS a_2_subnet 
FROM a AS a_1, a AS a_2 
WHERE NOT cidr_overlap(a_1.subnet, a_2.subnet) AND a_1.id > a_2.id
2016-05-06 10:29:31,022 INFO sqlalchemy.engine.base.Engine ()
192.168.2.0/24 192.168.1.0/24

@namnh68
Copy link

namnh68 commented May 8, 2016

Many thanks Mr.Mike

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment