├── .gitignore ├── README.md ├── reset_log_data.sql ├── reset_extensions_data.sql ├── reset_increment_ids.sql └── reset_test_data.sql /.gitignore: -------------------------------------------------------------------------------- 1 | /.project 2 | /.settings/ -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ## Magento reset scripts 2 | 3 | **Why?** 4 | Installing an extension just to delete test orders before site launch seems excessive. Simply import these sql scripts to reset testdata in Magento stores. 5 | 6 | **How?** 7 | Download & make changes as you like. Use with your favourite mysql admin tool. Beware, these all delete data, so you should of course confirm backups before using any of these. 8 | 9 | **What?** 10 | - **reset_increment_ids** - replaces current increment ids for orders with the values you specify in the file. Runs per store, affects orders, invoices, shipments and credit memos. 11 | 12 | - **reset_test_data** - empties all core Magento tables known to hold regular customer data and sets increment id to 1 13 | 14 | - **reset_extensions_data** - empties tables holding customer data for various extensions. 15 | 16 | - **reset_log_data** - will empty the Magento logs for visitors, urls etc. These tables usually grow quite large over time and not all merchants are interested in the data. 17 | 18 | Please contribute! Improved code, more extensions, tips or constructive criticism are all very welcome 19 | -------------------------------------------------------------------------------- /reset_log_data.sql: -------------------------------------------------------------------------------- 1 | -- Truncate logs for Magento -- 2 | -- This will delete data - make sure you have backups! 3 | -- reset_log_data.sql will empty Magento logs for visitors, urls etc. 4 | -- These tables usually grow quite large over time and some merchants are not interested in the data. 5 | -- Merged and compiled by ccondrup for CCData.no 6 | 7 | SET FOREIGN_KEY_CHECKS = 0; 8 | SET NAMES utf8; -- Make sure to preserve Unicode characters outside Basic Multilingual Plane (Æ,ö, etc etc.) 9 | 10 | -- Mark those pesky notifications as read 11 | UPDATE `adminnotification_inbox` SET is_read=1; 12 | 13 | -- Reset report data 14 | DELETE FROM `report_event` 15 | WHERE event_type_id IN ( 16 | SELECT event_type_id 17 | FROM `report_event_types` 18 | WHERE event_name IN ( 19 | 'catalog_product_view', 'sendfriend_product', 'catalog_product_compare_add_product', 20 | 'checkout_cart_add_product', 'wishlist_add_product', 'wishlist_share' 21 | ) 22 | ); 23 | 24 | -- Create a tmp table to hold the names of tables we want to service 25 | DROP TEMPORARY TABLE IF EXISTS `tmp_trunctables`; 26 | CREATE TEMPORARY TABLE IF NOT EXISTS `tmp_trunctables` ( 27 | `tname` varchar(100) NOT NULL 28 | ) ENGINE=MyISAM DEFAULT CHARSET=utf8; 29 | 30 | -- List of tables to both truncate and set incrementid=1 31 | INSERT INTO `tmp_trunctables` VALUES 32 | ('log_url'), 33 | ('log_url_info'), 34 | ('log_visitor'), 35 | ('log_visitor_info'), 36 | ('log_visitor_online'), 37 | ('report_compared_product_index'), 38 | ('report_viewed_product_index') 39 | ; 40 | 41 | -- This is the sproc which runs through the tmp table and truncates 42 | DELIMITER || 43 | DROP PROCEDURE IF EXISTS `ccdata_empty_testdata`|| 44 | 45 | CREATE PROCEDURE ccdata_empty_testdata () 46 | MODIFIES SQL DATA 47 | BEGIN 48 | DECLARE t1 VARCHAR(100); 49 | DECLARE done INT; 50 | DECLARE cur_1 CURSOR FOR SELECT tname FROM `tmp_trunctables` WHERE 1; 51 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; 52 | OPEN cur_1; 53 | REPEAT 54 | FETCH cur_1 INTO t1; 55 | 56 | SET @sql1 = CONCAT('TRUNCATE ', t1, ';'); 57 | PREPARE s1 from @sql1; 58 | EXECUTE s1; 59 | 60 | SET @sql2 = CONCAT('ALTER TABLE ', t1, ' AUTO_INCREMENT=1;'); 61 | PREPARE s2 from @sql2; 62 | EXECUTE s2; 63 | 64 | UNTIL done = 1 65 | END REPEAT; 66 | CLOSE cur_1; 67 | END;|| 68 | 69 | CALL ccdata_empty_testdata()|| 70 | DROP PROCEDURE IF EXISTS `ccdata_empty_testdata`|| 71 | DELIMITER ;|| 72 | 73 | SET FOREIGN_KEY_CHECKS = 1; 74 | -------------------------------------------------------------------------------- /reset_extensions_data.sql: -------------------------------------------------------------------------------- 1 | -- Reset data for misc. Magento extensions 2 | -- This will delete data - make sure you have backups! 3 | -- Created by ccondrup for CCData.no 4 | 5 | SET FOREIGN_KEY_CHECKS = 0; 6 | SET NAMES utf8; -- Make sure to preserve Unicode characters outside Basic Multilingual Plane (Æ,ö, etc etc.) 7 | 8 | -- Create a tmp table to hold the names of tables we want to service 9 | DROP TEMPORARY TABLE IF EXISTS `tmp_trunctables`; 10 | CREATE TEMPORARY TABLE IF NOT EXISTS `tmp_trunctables` ( 11 | `tname` varchar(100) NOT NULL 12 | ) ENGINE=MyISAM DEFAULT CHARSET=utf8; 13 | 14 | -- DIBS.eu Payment Gateway 15 | INSERT INTO `tmp_trunctables` VALUES ('dibs_orderdata'), ('dibs_order_status'); 16 | 17 | -- MagePlace.com Social Login 18 | INSERT INTO `tmp_trunctables` VALUES ('googleconnect_synch'), ('twitterconnect_synch'); 19 | 20 | -- MageMonkey 21 | INSERT INTO `tmp_trunctables` VALUES ('magemonkey_ecommerce360'); 22 | 23 | -- TemplatesMaster.com Helpmate 24 | INSERT INTO `tmp_trunctables` VALUES ('tm_helpmate_theard'), ('tm_helpmate_ticket'); 25 | 26 | -- Go ahead, add lines for more extensions and submit as pull request! 27 | -- INSERT INTO `tmp_trunctables` VALUES (''); 28 | 29 | -- Test nonexistant table: 30 | -- INSERT INTO `tmp_trunctables` VALUES ('mytestfoobar'); 31 | 32 | 33 | -- This is the sproc which runs through the tmp table and truncates 34 | DELIMITER || 35 | DROP PROCEDURE IF EXISTS `ccdata_empty_testdata`|| 36 | 37 | CREATE PROCEDURE ccdata_empty_testdata () 38 | MODIFIES SQL DATA 39 | BEGIN 40 | DECLARE dbname,t1 VARCHAR(100); 41 | DECLARE tcount,done INT; 42 | DECLARE cur_1 CURSOR FOR SELECT tname FROM `tmp_trunctables` WHERE 1; 43 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; 44 | OPEN cur_1; 45 | REPEAT 46 | FETCH cur_1 INTO t1; 47 | 48 | -- Check whether given db table exists 49 | SELECT database() INTO dbname; 50 | SELECT COUNT(*) INTO tcount FROM information_schema.TABLES 51 | WHERE TABLE_NAME=t1 and TABLE_SCHEMA=dbname; 52 | 53 | IF (tcount > 0) THEN 54 | SET @sql1 = CONCAT('TRUNCATE ', t1, ';'); 55 | PREPARE s1 from @sql1; 56 | EXECUTE s1; 57 | 58 | SET @sql2 = CONCAT('ALTER TABLE ', t1, ' AUTO_INCREMENT=1;'); 59 | PREPARE s2 from @sql2; 60 | EXECUTE s2; 61 | END IF; 62 | 63 | UNTIL done = 1 64 | END REPEAT; 65 | CLOSE cur_1; 66 | END;|| 67 | 68 | CALL ccdata_empty_testdata()|| 69 | DROP PROCEDURE IF EXISTS `ccdata_empty_testdata`|| 70 | DELIMITER ;|| 71 | 72 | SET FOREIGN_KEY_CHECKS = 1; 73 | -------------------------------------------------------------------------------- /reset_increment_ids.sql: -------------------------------------------------------------------------------- 1 | -- Resets testdata for Magento -- 2 | -- This will delete your existing increment ids for orders, invoices, creditmemos and shipment and replace with values specified 3 | -- Credits: Elias Interactive http://goo.gl/E03d5 & ChiliPepperDesign http://goo.gl/FcWGx 4 | -- Merged and compiled by ccondrup for CCData.no 5 | 6 | -- Start config section. Set your options here -- 7 | -- For empty values, leave blank ('') rather than delete the variables -- 8 | SET @id_store := '3'; -- The id of the Mage store you wish to change. Run this script for each store. 9 | SET @id_prefix := NULL; -- Prefix for new numbers, alphanumeric is OK, NULL or numeric preferrable 10 | SET @nr_nextid := 10101; -- Next order id. Match padlength! Mage default 00000001 = 8 digits, means @nr_padding should be 8. 11 | SET @nr_padding := char_length(@nr_nextid); -- Automatic. Override if needed. How many digits was set for nr_nextid? Mage default 8 12 | -- The set values will result in next id = #310102 -- 13 | -- End config section. No need to edit below -- 14 | 15 | SET FOREIGN_KEY_CHECKS = 0; 16 | SET NAMES utf8; -- Make sure to preserve Unicode characters outside Basic Multilingual Plane (Æ,ö, etc etc.) 17 | 18 | -- First set pad length 19 | UPDATE `eav_entity_type` 20 | SET `increment_pad_length` = @nr_padding 21 | WHERE ( 22 | `entity_type_code` = 'order' 23 | OR `entity_type_code` = 'invoice' 24 | OR `entity_type_code` = 'shipment' 25 | OR `entity_type_code` = 'creditmemo' 26 | ); 27 | 28 | -- Create and run the procedure to set defaults for orders, invoices, shipments, credit memos 29 | DELIMITER || 30 | DROP PROCEDURE IF EXISTS `ccdata_set_defaults`|| 31 | 32 | CREATE PROCEDURE ccdata_set_defaults (IN id_store INT(5), IN id_prefix VARCHAR(15), IN nr_nextid VARCHAR(15)) 33 | MODIFIES SQL DATA 34 | BEGIN 35 | DECLARE id_type,done INT; 36 | DECLARE cur_1 CURSOR FOR SELECT entity_type_id FROM `eav_entity_type` WHERE entity_type_code IN ('order', 'invoice', 'creditmemo', 'shipment'); 37 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; 38 | IF id_prefix = 'NULL' THEN SET id_prefix = NULL; END IF; 39 | OPEN cur_1; 40 | REPEAT 41 | FETCH cur_1 INTO id_type; 42 | DELETE FROM `eav_entity_store` WHERE `entity_type_id` = id_type AND `store_id` = id_store; 43 | INSERT INTO `eav_entity_store` (`entity_type_id`, `store_id`, `increment_prefix`, `increment_last_id`) 44 | VALUES(id_type, id_store, id_prefix, CONCAT(CAST(id_store AS CHAR), nr_nextid)); 45 | UNTIL done = 1 46 | END REPEAT; 47 | CLOSE cur_1; 48 | END;|| 49 | 50 | CALL ccdata_set_defaults(@id_store, @id_prefix, @nr_nextid)|| 51 | DROP PROCEDURE IF EXISTS `ccdata_set_defaults`|| 52 | DELIMITER ;|| 53 | 54 | 55 | SET FOREIGN_KEY_CHECKS = 1; -------------------------------------------------------------------------------- /reset_test_data.sql: -------------------------------------------------------------------------------- 1 | -- Resets testdata for Magento -- 2 | -- This will delete data - make sure you have backups! 3 | -- Credits: Elias Interactive http://goo.gl/E03d5 & ChiliPepperDesign http://goo.gl/FcWGx 4 | -- Merged and compiled by ccondrup for CCData.no 5 | 6 | SET FOREIGN_KEY_CHECKS = 0; 7 | SET NAMES utf8; -- Make sure to preserve Unicode characters outside Basic Multilingual Plane (Æ,ö, etc etc.) 8 | 9 | -- Mark those pesky notifications as read 10 | UPDATE `adminnotification_inbox` SET is_read=1; 11 | 12 | -- Reset report data 13 | DELETE FROM `report_event` 14 | WHERE event_type_id IN ( 15 | SELECT event_type_id 16 | FROM `report_event_types` 17 | WHERE event_name IN ( 18 | 'catalog_product_view', 'sendfriend_product', 'catalog_product_compare_add_product', 19 | 'checkout_cart_add_product', 'wishlist_add_product', 'wishlist_share' 20 | ) 21 | ); 22 | 23 | -- Create a tmp table to hold the names of tables we want to service 24 | DROP TEMPORARY TABLE IF EXISTS `tmp_trunctables`; 25 | CREATE TEMPORARY TABLE IF NOT EXISTS `tmp_trunctables` ( 26 | `tname` varchar(100) NOT NULL 27 | ) ENGINE=MyISAM DEFAULT CHARSET=utf8; 28 | 29 | -- List of tables to both truncate and set incrementid=1 30 | INSERT INTO `tmp_trunctables` VALUES 31 | ('catalogsearch_query'), 32 | ('catalogsearch_result'), 33 | ('catalog_compare_item'), 34 | ('customer_address_entity'), 35 | ('customer_address_entity_datetime'), 36 | ('customer_address_entity_decimal'), 37 | ('customer_address_entity_int'), 38 | ('customer_address_entity_text'), 39 | ('customer_address_entity_varchar'), 40 | ('customer_entity'), 41 | ('customer_entity_datetime'), 42 | ('customer_entity_decimal'), 43 | ('customer_entity_int'), 44 | ('customer_entity_text'), 45 | ('customer_entity_varchar'), 46 | ('downloadable_link_purchased'), 47 | ('downloadable_link_purchased_item'), 48 | ('log_customer'), 49 | ('log_quote'), 50 | ('log_summary'), 51 | ('log_summary_type'), 52 | ('log_url'), 53 | ('log_url_info'), 54 | ('log_visitor'), 55 | ('log_visitor_info'), 56 | ('log_visitor_online'), 57 | ('newsletter_queue'), 58 | ('newsletter_queue_link'), 59 | ('newsletter_queue_store_link'), 60 | ('newsletter_subscriber'), 61 | ('rating_option'), 62 | ('rating_option_vote'), 63 | ('rating_option_vote_aggregated'), 64 | ('rating_store'), 65 | ('rating_title'), 66 | ('report_compared_product_index'), 67 | ('report_event'), 68 | ('report_viewed_product_index'), 69 | ('review'), 70 | ('review_detail'), 71 | ('review_entity_summary'), 72 | ('review_store'), 73 | ('salesrule_coupon_usage'), 74 | ('salesrule_customer'), 75 | ('sales_bestsellers_aggregated_daily'), 76 | ('sales_bestsellers_aggregated_monthly'), 77 | ('sales_bestsellers_aggregated_yearly'), 78 | ('sales_billing_agreement'), 79 | ('sales_billing_agreement_order'), 80 | ('sales_flat_creditmemo'), 81 | ('sales_flat_creditmemo_comment'), 82 | ('sales_flat_creditmemo_grid'), 83 | ('sales_flat_creditmemo_item'), 84 | ('sales_flat_invoice'), 85 | ('sales_flat_invoice_comment'), 86 | ('sales_flat_invoice_grid'), 87 | ('sales_flat_invoice_item'), 88 | ('sales_flat_order'), 89 | ('sales_flat_order_address'), 90 | ('sales_flat_order_grid'), 91 | ('sales_flat_order_item'), 92 | ('sales_flat_order_payment'), 93 | ('sales_flat_order_status_history'), 94 | ('sales_flat_quote'), 95 | ('sales_flat_quote_address'), 96 | ('sales_flat_quote_address_item'), 97 | ('sales_flat_quote_item'), 98 | ('sales_flat_quote_item_option'), 99 | ('sales_flat_quote_payment'), 100 | ('sales_flat_quote_shipping_rate'), 101 | ('sales_flat_shipment'), 102 | ('sales_flat_shipment_comment'), 103 | ('sales_flat_shipment_grid'), 104 | ('sales_flat_shipment_item'), 105 | ('sales_flat_shipment_track'), 106 | ('sales_invoiced_aggregated'), 107 | ('sales_invoiced_aggregated_order'), 108 | ('sales_order_aggregated_created'), 109 | ('sales_order_aggregated_updated'), 110 | ('sales_order_tax'), 111 | ('sales_order_tax_item'), 112 | ('sales_payment_transaction'), 113 | ('sales_recurring_profile'), 114 | ('sales_recurring_profile_order'), 115 | ('sales_refunded_aggregated'), 116 | ('sales_refunded_aggregated_order'), 117 | ('sales_shipping_aggregated'), 118 | ('sales_shipping_aggregated_order'), 119 | ('sendfriend_log'), 120 | ('tag'), 121 | ('tag_relation'), 122 | ('tag_summary'), 123 | ('wishlist'), 124 | ('wishlist_item'), 125 | ('wishlist_item_option') 126 | ; 127 | 128 | -- This is the sproc which runs through the tmp table and truncates 129 | DELIMITER || 130 | DROP PROCEDURE IF EXISTS `ccdata_empty_testdata`|| 131 | 132 | CREATE PROCEDURE ccdata_empty_testdata () 133 | MODIFIES SQL DATA 134 | BEGIN 135 | DECLARE t1 VARCHAR(100); 136 | DECLARE done INT; 137 | DECLARE cur_1 CURSOR FOR SELECT tname FROM `tmp_trunctables` WHERE 1; 138 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; 139 | OPEN cur_1; 140 | REPEAT 141 | FETCH cur_1 INTO t1; 142 | 143 | SET @sql1 = CONCAT('TRUNCATE ', t1, ';'); 144 | PREPARE s1 from @sql1; 145 | EXECUTE s1; 146 | 147 | SET @sql2 = CONCAT('ALTER TABLE ', t1, ' AUTO_INCREMENT=1;'); 148 | PREPARE s2 from @sql2; 149 | EXECUTE s2; 150 | 151 | UNTIL done = 1 152 | END REPEAT; 153 | CLOSE cur_1; 154 | END;|| 155 | 156 | CALL ccdata_empty_testdata()|| 157 | DROP PROCEDURE IF EXISTS `ccdata_empty_testdata`|| 158 | DELIMITER ;|| 159 | 160 | SET FOREIGN_KEY_CHECKS = 1; 161 | --------------------------------------------------------------------------------