A Little Noise

December 10, 2011

MidPoint of a LineString

Filed under: MySQL — snoyes @ 10:12 am

CREATE FUNCTION MidPoint(ls LINESTRING)
RETURNS POINT
DETERMINISTIC
BEGIN
DECLARE len double;
DECLARE workLength double DEFAULT 0;
DECLARE workPoint int DEFAULT 1;
DECLARE point0 POINT;
DECLARE point1 POINT;
DECLARE distanceOver double;
DECLARE segmentLength double;

IF (NumPoints(ls) = 1) THEN return PointN(ls, 1); END IF;

-- find half the length of the linestring
SET len := GLength(ls) / 2;

-- walk the linestring until we exceed the distance
WHILE (workLength < len) DO SET point0 = PointN(ls, workPoint); SET workPoint := workPoint + 1; SET point1 = PointN(ls, workPoint); SET segmentLength = GLength(LineString(point0, point1)); SET workLength := workLength + segmentLength; END WHILE; -- distance to backup SET distanceOver = workLength - len; -- midpoint is distanceOver back down the last segement RETURN POINT( X(point1) - distanceOver / segmentLength * (X(point1) - X(point0)), Y(point1) - distanceOver / segmentLength * (Y(point1) - Y(point0)) ); END

November 9, 2011

Quiz: A More Perfect UNION

Filed under: MySQL Gotchas — snoyes @ 2:59 pm

Today I saw a query like this:
SELECT d FROM t;

Performance was terrible. I ran out of patience after several minutes and killed the thread.

I changed the query to this:
(SELECT d FROM t) UNION ALL (SELECT NULL LIMIT 0);

It completed in under 3 seconds.

Can you explain how a no-op UNION so dramatically improved performance? (I couldn’t have, without help from Jesper Krogh and James Day).

Hint #1 ▼

Hint #2 ▼

Hint #3 ▼

Hint #4 ▼

Answer ▼

October 12, 2011

Yet another way to count occurences of a substring in a string

Filed under: MySQL — snoyes @ 11:20 am

In response to http://forge.mysql.com/snippets/view.php?id=60 – adding support to count strings, not just characters

(
  character_length(<string1>)
  - character_length(REPLACE(<string1>, <searchString>, '')
) / character_length(<searchString>)

Easter date

Filed under: MySQL — snoyes @ 11:19 am

Finds the date for Easter (Western) given a year.
Sample usage: SELECT easter(YEAR(NOW()));

DELIMITER //
CREATE FUNCTION easter(inYear YEAR) RETURNS DATE DETERMINISTIC
BEGIN
    DECLARE a, b, c, d, e, k, m, n, p, q INT;

    DECLARE easter DATE;

    SET k = FLOOR(inYear / 100);
    SET a = MOD(inYear, 19);
    SET b = MOD(inYear, 4);
    SET c = MOD(inYear, 7);
    SET q = FLOOR(k / 4);
    SET p = FLOOR((13 + 8 * k) / 25);
    SET m = MOD((15-p+k-q), 30);
    SET d = MOD((19 * a + m), 30);
    SET n = MOD((4+k-q), 7);
    SET e = MOD((2*b+4*c+6*d+n), 7);

    SET easter = CASE
        WHEN d + e <= 9 THEN CONCAT_WS('-', inYear, '03', 22 + d + e)
        WHEN d = 29 AND e = 6 THEN CONCAT_WS('-', inYear, '04-19')
        WHEN d = 28 AND e = 6 AND a > 10 THEN CONCAT_WS('-', inYear, '04-18')
        ELSE CONCAT_WS('-', inYear, '04', LPAD(d + e - 9, 2, 0))
    END;

    RETURN easter;
END
//
DELIMITER ;

Show all grants

Filed under: MySQL — snoyes @ 11:18 am

A stored procedure to show all grants in the database.

USE mysql;

DELIMITER //
CREATE PROCEDURE showAllGrants() BEGIN
    DECLARE done INT DEFAULT 0;
    DECLARE theUser CHAR(16);
    DECLARE theHost CHAR(60);
    DECLARE cur1 CURSOR FOR SELECT user, host FROM mysql.user;
    DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET done = 1;
    OPEN cur1;

    REPEAT
        FETCH cur1 INTO theUser, theHost;
        IF NOT done THEN
            SET @sql := CONCAT('SHOW GRANTS FOR ', QUOTE(theUser), '@', QUOTE(theHost));
            PREPARE grantStatement FROM @sql;
            EXECUTE grantStatement;
            DROP PREPARE grantStatement;
        END IF;
    UNTIL done END REPEAT;

    CLOSE cur1;
END//
DELIMITER ;

CALL showAllGrants();

Roman numerals

Filed under: MySQL — snoyes @ 11:18 am

Convert an integer in the range 0 to 3999 to Roman numerals.

CREATE FUNCTION `toRoman`(inArabic int unsigned) RETURNS varchar(15) CHARSET latin1 DETERMINISTIC
BEGIN
    DECLARE numeral CHAR(7) DEFAULT 'IVXLCDM';

    DECLARE stringInUse CHAR(3);
    DECLARE position tinyint DEFAULT 1;
    DECLARE currentDigit tinyint;

    DECLARE returnValue VARCHAR(15) DEFAULT '';

    IF(inArabic > 3999) THEN RETURN 'overflow'; END IF;
    IF(inArabic = 0) THEN RETURN 'N'; END IF;

    WHILE position <= CEIL(LOG10(inArabic + .1)) DO
        SET currentDigit := MOD(FLOOR(inArabic / POW(10, position - 1)), 10);

        SET returnValue := CONCAT(
            CASE currentDigit 
                WHEN 4 THEN CONCAT(SUBSTRING(numeral, position * 2 - 1, 1), SUBSTRING(numeral, position * 2, 1))
                WHEN 9 THEN CONCAT(SUBSTRING(numeral, position * 2 - 1, 1), SUBSTRING(numeral, position * 2 + 1, 1))
                ELSE CONCAT(
                    REPEAT(SUBSTRING(numeral, position * 2, 1), currentDigit >= 5),
                    REPEAT(SUBSTRING(numeral, position * 2 - 1, 1), MOD(currentDigit, 5))
                )
            END,
            returnValue);

        SET position := position + 1;
    END WHILE;
    RETURN returnValue;
END

SHOW CREATE TRIGGER 5.0

Filed under: MySQL — snoyes @ 11:17 am

SHOW CREATE TRIGGER for 5.0 – 5.1.20

CREATE FUNCTION SHOW_CREATE_TRIGGER(in_trigger varchar(255)) 
RETURNS text READS SQL DATA 
BEGIN
    DECLARE returnText text;
    SELECT CONCAT_WS(
        " ",
        "CREATE TRIGGER", 
        TRIGGER_NAME, 
        ACTION_TIMING, 
        EVENT_MANIPULATION, 
        "ON", 
        EVENT_OBJECT_TABLE, 
        "FOR EACH ROW", 
        ACTION_STATEMENT) into returnText
    FROM information_schema.triggers;
RETURN returnText;
END

Reverse Roman Numerals

Filed under: MySQL — snoyes @ 11:16 am

Translate from Roman Numerals back to decimal. Legal range is 0 to 3999 (that is, N to MMMCMXCIX) You can use IV or IIII for 4. You could even use a string of twenty I’s for 20, but there’s a string limit of 15, since that’s the length of the biggest well-formed numeral below 3999.

CREATE FUNCTION fromRoman (inRoman varchar(15)) RETURNS integer DETERMINISTIC
BEGIN

    DECLARE numeral CHAR(7) DEFAULT 'IVXLCDM';

    DECLARE digit TINYINT;
    DECLARE previous INT DEFAULT 0;
    DECLARE current INT;
    DECLARE sum INT DEFAULT 0;

    SET inRoman = UPPER(inRoman);

    WHILE LENGTH(inRoman) > 0 DO
        SET digit := LOCATE(RIGHT(inRoman, 1), numeral) - 1;
        SET current := POW(10, FLOOR(digit / 2)) * POW(5, MOD(digit, 2));
        SET sum := sum + POW(-1, current < previous) * current;
        SET previous := current;
        SET inRoman = LEFT(inRoman, LENGTH(inRoman) - 1);
    END WHILE;

    RETURN sum;
END

Extract range characters

Filed under: MySQL — snoyes @ 11:15 am

Given a source string and a two-character range string, extracts all characters from the source that fall within the range. Sort of a simple version of the [A-Z] syntax from regular expressions.

Examples:
extractRange(‘123-ABC-456’, ‘AZ’) returns ‘ABC’
extractRange(‘123-ABC-456′, ’09’) returns ‘123456’

CREATE FUNCTION extractRange(inString TEXT, inRange char(2)) 
RETURNS TEXT 
DETERMINISTIC
BEGIN
DECLARE returnString TEXT DEFAULT '';
DECLARE pointer INT DEFAULT 1;
WHILE pointer <= CHAR_LENGTH(inString) DO
    IF MID(inString, pointer, 1) BETWEEN LEFT(inRange, 1) AND RIGHT(inRange, 1) THEN
        SET returnString := CONCAT(returnString, MID(inString, pointer, 1));
    END IF;
    SET pointer := pointer + 1;
END WHILE;
return returnString;
END

FIND_IN_WILD_SET and FIND_WILD_IN_SET

Filed under: MySQL — snoyes @ 11:14 am

Two functions that work just like FIND_IN_SET, but support the % wildcard.

SELECT FIND_WILD_IN_SET(‘%tack’, ‘haystack,bale,heap,needle,pile’);
SELECT FIND_IN_WILD_SET(‘pin’, ‘haystack,bale,heap,needle,pi%’);

DROP FUNCTION IF EXISTS FIND_IN_WILD_SET;
DROP FUNCTION IF EXISTS FIND_WILD_IN_SET;

DELIMITER //

CREATE FUNCTION FIND_IN_WILD_SET(theString text, theSet text)
RETURNS boolean
DETERMINISTIC
BEGIN

DECLARE delimiterCount int;
DECLARE pos int DEFAULT 0;
DECLARE setElement text;
DECLARE returnValue boolean DEFAULT FALSE;

SET delimiterCount := CHARACTER_LENGTH(theSet) - CHARACTER_LENGTH(REPLACE(theSet, ',', ''));

WHILE (pos <= delimiterCount) DO
    BEGIN 
        SET setElement := SUBSTRING_INDEX(SUBSTRING_INDEX(theSet, ',', pos+1), ',', -1);
        SET returnValue := returnValue OR (theString LIKE setElement);
        SET pos := pos + 1;

    END;    
END WHILE;


RETURN returnValue;

END//

CREATE FUNCTION FIND_WILD_IN_SET(theString text, theSet text)
RETURNS boolean
DETERMINISTIC
BEGIN

DECLARE delimiterCount int;
DECLARE pos int DEFAULT 0;
DECLARE setElement text;
DECLARE returnValue boolean DEFAULT FALSE;

SET delimiterCount := CHARACTER_LENGTH(theSet) - CHARACTER_LENGTH(REPLACE(theSet, ',', ''));

WHILE (pos <= delimiterCount) DO
    BEGIN 
        SET setElement := SUBSTRING_INDEX(SUBSTRING_INDEX(theSet, ',', pos+1), ',', -1);
        SET returnValue := returnValue OR (setElement LIKE theString);
        SET pos := pos + 1;

    END;    
END WHILE;


RETURN returnValue;

END//

DELIMITER ;
« Newer PostsOlder Posts »

Powered by WordPress