├── LICENSE
├── README.md
├── camelCase.sql
├── camelCase_README.md
├── devLog.sql
├── devLog_README.md
├── getPhpSerializedArrayValueByKey.sql
└── getPhpSerializedArrayValueByKey_README.md
/LICENSE:
--------------------------------------------------------------------------------
1 | The MIT License (MIT)
2 |
3 | Copyright (c) 2014
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
22 |
23 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | MySQLToolBox
2 | ============
3 |
4 | Set of MySQL scripts which help working with database.
5 |
6 | Tools list:
7 |
8 |
9 | 1. Function **getPhpSerializedArrayValueByKey**
10 | *Function returns last value from serialized array by specific string key.*
11 |
12 | 2. Function/Procedure **devLog/devReset**
13 | *Two functions and procedures which helps in debuging other functions and procedures.*
14 |
15 |
16 | 3. Function **camelCase**
17 |
18 | *Function returns camelCase form of provided string using passed separator.*
19 |
--------------------------------------------------------------------------------
/camelCase.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | DROP FUNCTION IF EXISTS `camelCase`$$
4 |
5 | CREATE DEFINER=`root`@`localhost` FUNCTION `camelCase`(_string TEXT, _separator_char VARCHAR(1)) RETURNS TEXT CHARSET utf8
6 | DETERMINISTIC
7 | COMMENT 'Function returns camelCase form of provided string using passed separator'
8 | BEGIN
9 | /*
10 | Function returns camelCase form of provided string using passed separator.
11 |
12 | @author Adam Wnęk (http://kredyty-chwilowki.pl/)
13 | @licence MIT
14 | @version 1.0
15 | */
16 | DECLARE _string_len INT UNSIGNED DEFAULT 0;
17 | DECLARE _string_words TEXT DEFAULT '';
18 | DECLARE _camel_case TEXT DEFAULT '';
19 | DECLARE _string_parts TEXT DEFAULT '';
20 | DECLARE _separator_location SMALLINT UNSIGNED DEFAULT 1;
21 |
22 | SET _string_len := LENGTH(_string);
23 | SET _string_parts := _string;
24 |
25 | -- while (separator is before end of string and part of a string is not empty) and we have separator in part of a string
26 | WHILE ((LOCATE(_separator_char,_string_parts) <= _string_len AND LENGTH(_string_parts) > 0)) AND _separator_location > 0 DO
27 |
28 | SET _separator_location := LOCATE(_separator_char,_string_parts);
29 |
30 | IF _separator_location > 0 THEN
31 | -- get word before separator
32 | SET _string_words := SUBSTRING(_string_parts, 1, _separator_location-1);
33 | -- cut after separator (without it) to end of string
34 | SET _string_parts := SUBSTRING(_string_parts, _separator_location+1);
35 | ELSE
36 | -- no separator - we have last word
37 | SET _string_words := _string_parts;
38 | END IF;
39 | -- every word concat to camelCase form
40 | -- first letter uppercase and rest lowercase
41 | SET _camel_case := CONCAT(_camel_case,CONCAT(UCASE(SUBSTRING(_string_words, 1, 1)),LCASE(SUBSTRING(_string_words, 2))));
42 | END WHILE;
43 | RETURN _camel_case;
44 | END$$
45 |
46 | DELIMITER ;
47 |
--------------------------------------------------------------------------------
/camelCase_README.md:
--------------------------------------------------------------------------------
1 | camelCase
2 | ============
3 |
4 | ###Description
5 | Function returns camelCase form of provided string using passed separator.
6 |
7 | ##Specification
8 |
9 | ```mysql
10 | FUNCTION `camelCase`(_string TEXT, _separator_char VARCHAR(1))
11 | RETURNS TEXT;
12 | ```
13 |
14 | ##Example usage:
15 |
16 | ```mysql
17 | SELECT
18 | camelCase('lorem-Ipsum','-') AS 'first'
19 | ,camelCase('lorem ipsum',' ') AS 'second'
20 | ,camelCase('Lorem_Ipsum','_') AS 'third'
21 | ;
22 | ```
23 | ###Result
24 | |"first"|"second"|"third"|
25 | |-------------|-------------|-------------|
26 | |LoremIpsum|LoremIpsum|LoremIpsum|
27 |
--------------------------------------------------------------------------------
/devLog.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 | DROP PROCEDURE IF EXISTS `devLog`$$
3 | CREATE
4 | PROCEDURE `devLog`(concat_data TEXT)
5 |
6 | BEGIN
7 | CREATE TEMPORARY TABLE IF NOT EXISTS `devLog` (
8 | `id` INT(11) UNSIGNED NOT NULL AUTO_INCREMENT,
9 | `concat_data` TEXT,
10 | `date` DATETIME,
11 | PRIMARY KEY (`id`)
12 | ) ENGINE=INNODB DEFAULT CHARSET=utf8;
13 | INSERT INTO devLog (`concat_data`,`date`) VALUES (concat_data,NOW());
14 | END$$
15 |
16 | DELIMITER ;
17 |
18 | DELIMITER $$
19 | DROP FUNCTION IF EXISTS `devLog`$$
20 | CREATE
21 | FUNCTION `devLog`(concat_data TEXT)
22 | RETURNS TEXT DETERMINISTIC
23 | COMMENT 'Function is only adapter for procedure so it can be used in sql query'
24 | BEGIN
25 | CALL devLog(concat_data);
26 | RETURN concat_data;
27 | END$$
28 |
29 | DELIMITER ;
30 |
31 | DELIMITER $$
32 | DROP PROCEDURE IF EXISTS `devReset`$$
33 | CREATE
34 | PROCEDURE `devReset`()
35 |
36 | BEGIN
37 |
38 | DROP TEMPORARY TABLE IF EXISTS `devLog`;
39 | CREATE TEMPORARY TABLE IF NOT EXISTS `devLog` (
40 | `id` INT(11) UNSIGNED NOT NULL AUTO_INCREMENT,
41 | `concat_data` TEXT,
42 | `date` DATETIME,
43 | PRIMARY KEY (`id`)
44 | ) ENGINE=INNODB DEFAULT CHARSET=utf8;
45 |
46 | END$$
47 |
48 | DELIMITER ;
49 |
50 | DELIMITER $$
51 | DROP FUNCTION IF EXISTS `devReset`$$
52 | CREATE
53 | FUNCTION `devReset`()
54 | RETURNS TEXT DETERMINISTIC
55 | COMMENT 'Function is only adapter for procedure so it can be used in sql query'
56 | BEGIN
57 | CALL devReset();
58 | RETURN '';
59 | END$$
60 |
61 | DELIMITER ;
62 |
--------------------------------------------------------------------------------
/devLog_README.md:
--------------------------------------------------------------------------------
1 | devLog/devReset
2 | ============
3 |
4 | ###Description
5 | Below two procedures/functions are useful in data debuging.
6 |
7 | Collecting data is based on concating all informations you need with separator.
8 |
9 | ##Specification
10 |
11 | ```mysql
12 | PROCEDURE devLog(concat_data TEXT)
13 |
14 | FUNCTION `devLog`(concat_data TEXT) -- only adapter for procedure devLog
15 | RETURNS TEXT -- RETURN concat_data;
16 |
17 | PROCEDURE `devReset`()
18 |
19 | FUNCTION `devReset`() -- only adapter for procedure devReset
20 | RETURNS TEXT -- RETURN '';
21 | ```
22 |
23 | ##Example usage:
24 |
25 | #####Usage in queries, subqueries
26 |
27 | ```mysql
28 | SELECT devReset();
29 |
30 | CALL devLog('start debug1');
31 |
32 | SELECT
33 | T.id,T.column_1
34 | FROM (
35 | SELECT
36 | id,column_1,devLog(CONCAT_WS(' | ',id,column_1,id*column_1)) AS debug
37 | FROM
38 | simple_table
39 | WHERE
40 | `id` BETWEEN 100 AND 105
41 | ) AS T;
42 |
43 | SELECT * FROM devLog;
44 | ```
45 | ###Result
46 | |"id"|"concat_data"|"date"|
47 | |-------------|-------------|-------------|
48 | |"1"|"start debug1"|"2015-06-19 08:40:20"|
49 | |"2"|"100 \| 647075 \| 64707500"|"2015-06-19 08:40:29"|
50 | |"3"|"101 \| 1141814 \| 115323214"|"2015-06-19 08:40:29"|
51 | |"4"|"102 \| 1141832 \| 116466864"|"2015-06-19 08:40:29"|
52 | |"5"|"103 \| 1142609 \| 117688727"|"2015-06-19 08:40:29"|
53 | |"6"|"104 \| 1141848 \| 118752192"|"2015-06-19 08:40:29"|
54 | |"7"|"105 \| 1142755 \| 119989275"|"2015-06-19 08:40:29"|
55 |
56 | #####Usage in procedures
57 |
58 | ```mysql
59 | SELECT devReset();
60 | CALL devLog('start debug2');
61 |
62 | DELIMITER $$
63 | CREATE PROCEDURE sample_proc()
64 | BEGIN
65 | DECLARE _i INT;
66 | SET _i = 0;
67 |
68 | WHILE _i < 5 DO
69 | CALL devLog(CONCAT_WS(' | ',_i,POW(_i,2)));
70 | SET _i = _i + 1;
71 | END WHILE;
72 |
73 | END$$
74 | DELIMITER ;
75 |
76 | CALL sample_proc();
77 |
78 | DROP PROCEDURE sample_proc;
79 |
80 | SELECT * FROM devLog;
81 | ```
82 |
83 | |"id"|"concat_data"|"date"|
84 | |-------------|-------------|-------------|
85 | |"1"|"start debug2"|"2015-06-19 06:54:44"|
86 | |"2"|"0 \| 0"|"2015-06-19 06:54:49"|
87 | |"3"|"1 \| 1"|"2015-06-19 06:54:49"|
88 | |"4"|"2 \| 4"|"2015-06-19 06:54:49"|
89 | |"5"|"3 \| 9"|"2015-06-19 06:54:49"|
90 | |"6"|"4 \| 16"|"2015-06-19 06:54:49"|
91 |
92 | #####Using in functions
93 |
94 | ```mysql
95 | SELECT devReset();
96 | CALL devLog('start debug3');
97 |
98 | DELIMITER $$
99 |
100 | CREATE
101 | FUNCTION `sample_func`(input VARCHAR(20))
102 | RETURNS VARCHAR(20)
103 | DETERMINISTIC
104 | BEGIN
105 | DECLARE _output VARCHAR(32);
106 | SET _output := MD5(input);
107 | CALL devLog(CONCAT_WS(' | ','input: ',input,'_output: ',_output));
108 | RETURN _output;
109 | END$$
110 | DELIMITER ;
111 |
112 | SELECT sample_func('example');
113 |
114 | DROP FUNCTION sample_func;
115 |
116 | SELECT * FROM devLog;
117 | ```
118 |
119 | |"id"|"concat_data"|"date"|
120 | |-------------|-------------|-------------|
121 | |"1"|"input: \| example \| _output: \| 1a79a4d60de6718e8e5b326e338ae533"|"2015-06-19 07:17:56"|
122 |
123 | Further usage depends on Your creativity...
124 |
--------------------------------------------------------------------------------
/getPhpSerializedArrayValueByKey.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | CREATE DEFINER=`root`@`localhost` FUNCTION `getPhpSerializedArrayValueByKey`(_input_string TEXT, _key TEXT) RETURNS TEXT CHARSET utf8 COLLATE utf8_polish_ci
4 | DETERMINISTIC
5 | COMMENT 'Function returns last value from serialized array by specific string key.'
6 | BEGIN
7 | /*
8 | Function returns last value from serialized array by specific string key.
9 |
10 | @author Adam Wnęk (http://kredyty-chwilowki.pl/)
11 | @licence MIT
12 | @version 1.2
13 | */
14 | -- required variables
15 | DECLARE __output_part,__output,__extra_byte_counter,__extra_byte_number,__value_type,__array_part_temp TEXT;
16 | DECLARE __value_length,__char_ord,__start,__char_counter,__non_multibyte_length,__array_close_bracket_counter,__array_open_bracket_counter INT SIGNED;
17 | SET __output := NULL;
18 |
19 | -- check if key exists in input
20 | IF LOCATE(CONCAT('s:',LENGTH(_key),':"',_key,'";'), _input_string) != 0 THEN
21 |
22 | -- cut from right to key
23 | SET __output_part := SUBSTRING_INDEX(_input_string,CONCAT('s:',LENGTH(_key),':"',_key,'";'),-1);
24 |
25 | -- get type of value [s,a,b,O,i,d]
26 | SET __value_type := SUBSTRING(SUBSTRING(__output_part, 1, CHAR_LENGTH(SUBSTRING_INDEX(__output_part,';',1))), 1, 1);
27 |
28 | -- custom cut depends of value type
29 | CASE
30 | WHEN __value_type = 'a' THEN
31 | -- we get proper array by counting open and close brackets
32 | SET __array_open_bracket_counter := 1;
33 | SET __array_close_bracket_counter := 0;
34 | -- without first open { so counter is 1
35 | SET __array_part_temp := SUBSTRING(__output_part FROM LOCATE('{',__output_part)+1);
36 |
37 | -- we start from first { and counting open and closet brackets until we find last closing one
38 | WHILE (__array_open_bracket_counter > 0 OR LENGTH(__array_part_temp) = 0) DO
39 | -- next { exists and its before closest }
40 | IF LOCATE('{',__array_part_temp) > 0 AND (LOCATE('{',__array_part_temp) < LOCATE('}',__array_part_temp)) THEN
41 | -- cut from found { + 1, to the end
42 | SET __array_open_bracket_counter := __array_open_bracket_counter + 1;
43 | SET __array_part_temp := SUBSTRING(__array_part_temp FROM LOCATE('{',__array_part_temp) + 1);
44 | ELSE
45 | -- cut from found } + 1, to the end
46 | SET __array_open_bracket_counter := __array_open_bracket_counter - 1;
47 | SET __array_close_bracket_counter := __array_close_bracket_counter + 1;
48 | SET __array_part_temp := SUBSTRING(__array_part_temp FROM LOCATE('}',__array_part_temp) + 1);
49 | END IF;
50 | END WHILE;
51 | -- final array is from beginning to [__array_close_bracket_counter] count of closing }
52 | SET __output := CONCAT(SUBSTRING_INDEX(__output_part,'}',__array_close_bracket_counter),'}');
53 |
54 | WHEN __value_type = 'd' OR __value_type = 'i' OR __value_type = 'b' THEN
55 |
56 | -- from left to first appearance of }, from right to first :
57 | SET __output := SUBSTRING_INDEX(SUBSTRING_INDEX(__output_part,';',1),':',-1);
58 |
59 | WHEN __value_type = 'O' THEN
60 |
61 | -- from left to first appearance of ;} but without it so we add it back
62 | SET __output := CONCAT(SUBSTRING_INDEX(__output_part,';}',1),';}');
63 |
64 | WHEN __value_type = 'N' THEN
65 | -- when we have null return empty string
66 | SET __output := NULL;
67 | ELSE
68 |
69 | -- get serialized length
70 | SET __value_length := SUBSTRING_INDEX(SUBSTRING_INDEX(SUBSTRING_INDEX(__output_part, ':', 2),':',-1),';',1);
71 |
72 | -- s:10:" -> 7 because we start after "
73 | -- we cut from the begin of our value to the end
74 | -- begin of our string is after: s[1] + :[1] + n[length of number] + :[1] + "[1] + [1](begin after ") = 5+n
75 | SET __output_part := SUBSTRING(__output_part, 5+LENGTH(__value_length));
76 |
77 | SET __char_counter := 1;
78 |
79 | -- real length to cut
80 | SET __non_multibyte_length := 0;
81 |
82 | SET __start := 0;
83 | -- check every char until [__value_length]
84 | WHILE __start < __value_length DO
85 |
86 | SET __char_ord := ORD(SUBSTR(__output_part,__char_counter,1));
87 |
88 | SET __extra_byte_number := 0;
89 | SET __extra_byte_counter := FLOOR(__char_ord / 256);
90 |
91 | -- we detect multibytechars and count them as one to substring correctly
92 | -- when we now how many chars make multibytechar we can use it to count what is non multibyte length of our value
93 | WHILE __extra_byte_counter > 0 DO
94 | SET __extra_byte_counter := FLOOR(__extra_byte_counter / 256);
95 | SET __extra_byte_number := __extra_byte_number+1;
96 | END WHILE;
97 |
98 | -- to every char i add extra multibyte number (for non multibyte char its 0)
99 | SET __start := __start + 1 + __extra_byte_number;
100 | SET __char_counter := __char_counter + 1;
101 | SET __non_multibyte_length := __non_multibyte_length +1;
102 |
103 | END WHILE;
104 |
105 | SET __output := SUBSTRING(__output_part,1,__non_multibyte_length);
106 |
107 | END CASE;
108 | END IF;
109 | RETURN __output;
110 | END$$
111 |
112 | DELIMITER ;
113 |
--------------------------------------------------------------------------------
/getPhpSerializedArrayValueByKey_README.md:
--------------------------------------------------------------------------------
1 | getPhpSerializedArrayValueByKey
2 | ============
3 |
4 | ##Specification
5 |
6 | ```mysql
7 | getPhpSerializedArrayValueByKey(_input_string TEXT, _key TEXT)
8 | returns TEXT CHARSET utf8;
9 | ```
10 |
11 | ##Simple example usage:
12 |
13 | ```php
14 | 'Lorem ipsum'
19 | )
20 | )
21 | );
22 | ?>
23 | ```
24 |
25 | ```mysql
26 | SET @s := 'a:1:{s:10:"custom_key";s:11:"Lorem ipsum";}';
27 |
28 | SELECT getPhpSerializedArrayValueByKey(@s,'custom_key') AS `value`;
29 | ```
30 |
31 | ###Result
32 | |value|
33 | |-------------|
34 | |Lorem ipsum|
35 |
36 | Returned value is string so it can be used in JOINS, WHERE, other functions like CONCAT etc.
37 |
38 | ##More advanced example usage:
39 |
40 | ```php
41 | foo = 'Lorem';
45 | $b->bar = 10;
46 |
47 | //return of this serialize is copied to mysql and set to @s
48 | print_r(
49 | serialize(array(
50 | 'a' => 5.99,
51 | 'b' => $b,
52 | 'c' => 8,
53 | 'd'=>'Lorem ipsum',
54 | 'e' => true,
55 | 'f' => array(
56 | 1,
57 | 2,
58 | '很' => 'Lorem',
59 | 'g' => array(
60 | 'h' => array(
61 | 8,
62 | array(
63 | 'i"' => 20
64 | )
65 | )
66 | )
67 | ),
68 | null => 'value1',
69 | true => 'value2',
70 | false => 'value3',
71 | 'Array' => 'value4',
72 | 'j' => array(0,1),
73 | 'null_value' => null
74 | )
75 | )
76 | );
77 | ```
78 |
79 | ```SQL
80 | -- MYSQL
81 | SET @s := 'a:12:{s:1:"a";d:5.9900000000000002;s:1:"b";O:8:"stdClass":2:{s:3:"foo";s:5:"Lorem";s:3:"bar";i:10;}s:1:"c";i:8;s:1:"d";s:11:"Lorem ipsum";s:1:"e";b:1;s:1:"f";a:4:{i:0;i:1;i:1;i:2;s:3:"很";s:5:"Lorem";s:1:"g";a:1:{s:1:"h";a:2:{i:0;i:8;i:1;a:1:{s:2:"i"";i:20;}}}}s:0:"";s:6:"value1";i:1;s:6:"value2";i:0;s:6:"value3";s:5:"Array";s:6:"value4";s:1:"j";a:2:{i:0;i:0;i:1;i:1;}s:10:"null_value";N;}';
82 |
83 |
84 | SELECT
85 | getPhpSerializedArrayValueByKey(@s,'a') AS a,
86 | getPhpSerializedArrayValueByKey(@s,'b') AS b,
87 | getPhpSerializedArrayValueByKey(@s,'c') AS c,
88 | getPhpSerializedArrayValueByKey(@s,'d') AS d,
89 | getPhpSerializedArrayValueByKey(@s,'e') AS e,
90 | getPhpSerializedArrayValueByKey(@s,'f') AS f,
91 | getPhpSerializedArrayValueByKey(@s,'很') AS 'multibytekey',
92 | getPhpSerializedArrayValueByKey(@s,'g') AS g,
93 | getPhpSerializedArrayValueByKey(@s,'h') AS h,
94 | getPhpSerializedArrayValueByKey(@s,'i"') AS 'i"',
95 | getPhpSerializedArrayValueByKey(@s,'') AS '',
96 | getPhpSerializedArrayValueByKey(@s,0) AS 'false',-- not work because only string keys work
97 | getPhpSerializedArrayValueByKey(@s,'Array') AS 'Array',
98 | getPhpSerializedArrayValueByKey(@s,'j') AS 'j',
99 | getPhpSerializedArrayValueByKey(@s,'null_value') AS null_value,
100 | getPhpSerializedArrayValueByKey(@s,'null_value') IS NULL AS 'is_null',
101 | IFNULL(getPhpSerializedArrayValueByKey(@s,'null_value'),'') AS 'ifnull'
102 | ;
103 | ```
104 |
105 | ###Result
106 |
107 | a|b|c|d|e|f|multibytekey|g|h|i"||false|Array|j|null_value|is_null|ifnull
108 | -------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|-------------|
109 | 5.9900000000000002131628207280300557613372802734375|O:8:"stdClass":2:{s:3:"foo";s:5:"Lorem";s:3:"bar";i:10;}|8|Lorem ipsum|1|a:4:{i:0;i:1;i:1;i:2;s:3:"很";s:5:"Lorem";s:1:"g";a:1:{s:1:"h";a:2:{i:0;i:8;i:1;a:1:{s:2:"i"";i:20;}}}}|Lorem|a:1:{s:1:"h";a:2:{i:0;i:8;i:1;a:1:{s:2:"i"";i:20;}}}|a:2:{i:0;i:8;i:1;a:1:{s:2:"i"";i:20;}}|20|value1|NULL|value4|a:2:{i:0;i:1;i:1;i:2;}|NULL|1|""
110 |
--------------------------------------------------------------------------------