Upgrade account_asset to account_asset_management ================================================= 1) account_asset_category ------------------------- SELECT column_name, data_type FROM information_schema.columns WHERE table_name = 'account_asset_category' AND column_name = 'method_period'; if method_period is type 'integer': ALTER TABLE account_asset_category RENAME method_period TO method_period_old; ALTER TABLE account_asset_category ADD COLUMN method_period character varying; UPDATE account_asset_category SET method_period = ( CASE WHEN method_period_old = 1 THEN 'month' WHEN method_period_old >= 12 THEN 'year' ELSE 'quarter' END); 2) account_asset_asset ---------------------- SELECT column_name FROM information_schema.columns WHERE table_name = 'account_asset_asset' AND column_name = 'purchase_date'; if purchase_date column: ALTER TABLE account_asset_asset RENAME purchase_date TO date_start; SELECT column_name FROM information_schema.columns WHERE table_name = 'account_asset_asset' AND column_name = 'asset_value'; if not asset_value column: ALTER TABLE account_asset_asset ADD column asset_value numeric; if asset_value column: SELECT asset_value FROM account_asset_asset WHERE asset_value IS NULL; if results: UPDATE account_asset_asset SET asset_value = purchase_value WHERE asset_value IS NULL; 3) DROP VIEW if exists asset_asset_report; 4) account_asset_depreciation_line ---------------------------------- SELECT column_name, data_type FROM information_schema.columns WHERE table_name = 'account_asset_depreciation_line' AND column_name = 'depreciation_date'; if depreciation_date column: if column depreciation_date is type 'character varying': ALTER TABLE account_asset_depreciation_line ALTER COLUMN depreciation_date TYPE date USING to_date(depreciation_date, 'YYYY-MM-DD'); ALTER TABLE account_asset_depreciation_line RENAME depreciation_date TO line_date; SELECT column_name FROM information_schema.columns WHERE table_name = 'account_asset_depreciation_line' AND column_name = 'sequence'; if column sequence: ALTER TABLE account_asset_depreciation_line DROP COLUMN sequence; SELECT column_name FROM information_schema.columns WHERE table_name = 'account_asset_depreciation_line' AND column_name = 'type'; if not column type: ALTER TABLE account_asset_depreciation_line ADD COLUMN type character varying; ALTER TABLE account_asset_depreciation_line ADD COLUMN previous_id integer; ALTER TABLE account_asset_depreciation_line ADD COLUMN init_entry boolean; ALTER TABLE account_asset_depreciation_line ALTER COLUMN remaining_value DROP NOT NULL; UPDATE account_asset_depreciation_line SET type='depreciate' WHERE type is NULL; 5) initialise previous_id ------------------------- /* plpgsql script to upgrade the account_asset_depreciation_line table for the account_asset 2.x version This script will initialise the previous_id field. Author : noviat (www.noviat.com) */ DO $$ DECLARE _max_records INTEGER := 10000; _asset_index INTEGER := 1; _asset_id INTEGER; _asset_ids INTEGER[]; _dl_index INTEGER; _dl_id INTEGER; _dl_ids INTEGER[]; _previous_id INTEGER; BEGIN SELECT ARRAY(SELECT id FROM account_asset_asset ORDER BY id ASC) INTO _asset_ids; RAISE INFO 'asset_ids = %', _asset_ids; IF array_length(_asset_ids, 1) < _max_records THEN _max_records = array_length(_asset_ids, 1); END IF; WHILE _asset_index <= _max_records LOOP _asset_id = _asset_ids[_asset_index]; SELECT ARRAY(SELECT id FROM account_asset_depreciation_line dl WHERE dl.asset_id=_asset_id AND type='depreciate' ORDER BY type, line_date) INTO _dl_ids; RAISE INFO 'processing asset_id = %', _asset_id; RAISE INFO 'processing dl_ids = %', _dl_ids; _dl_index := 1; _previous_id := 0; WHILE _dl_ids[_dl_index] IS NOT NULL LOOP _dl_id = _dl_ids[_dl_index]; IF _previous_id = 0 THEN UPDATE account_asset_depreciation_line SET previous_id = NULL WHERE id=_dl_id; ELSE UPDATE account_asset_depreciation_line SET previous_id = _previous_id WHERE id=_dl_id; END IF; _dl_index := _dl_index + 1; _previous_id = _dl_id; END LOOP; _asset_index := _asset_index + 1; END LOOP; END $$ LANGUAGE plpgsql; 6) uninstall/install -------------------- stop openerp ALTER TABLE account_asset_asset RENAME TO account_asset_asset_save; ALTER TABLE account_asset_category RENAME TO account_asset_category_save; ALTER TABLE account_asset_depreciation_line RENAME TO account_asset_depreciation_line_save; ALTER TABLE account_asset_history RENAME TO account_asset_history_save; Start openerp Uninstall module account_asset ALTER TABLE account_asset_asset_save RENAME TO account_asset_asset; ALTER TABLE account_asset_category_save RENAME TO account_asset_category; ALTER TABLE account_asset_depreciation_line_save RENAME TO account_asset_depreciation_line; ALTER TABLE account_asset_history_save RENAME TO account_asset_history; Install account_asset_management Start openerp 7) add init entries ------------------- /* plpgsql script to upgrade the account_asset_depreciation_line table for the account_asset 2.x version This script will add the init entries when not present. Author : noviat (www.noviat.com) */ DO $$ DECLARE _max_records INTEGER := 10000; _asset_index INTEGER := 1; _asset_id INTEGER; _asset_ids INTEGER[]; _asset account_asset_asset%ROWTYPE; _dl_ids INTEGER[]; _previous_id INTEGER; _aadl account_asset_depreciation_line%ROWTYPE; _init_id INTEGER; BEGIN SELECT ARRAY(SELECT id FROM account_asset_asset ORDER BY id ASC) INTO _asset_ids; RAISE INFO 'asset_ids = %', _asset_ids; IF array_length(_asset_ids, 1) < _max_records THEN _max_records = array_length(_asset_ids, 1); END IF; WHILE _asset_index <= _max_records LOOP _asset_id = _asset_ids[_asset_index]; SELECT * FROM account_asset_asset WHERE id = _asset_id INTO _asset; IF _asset.type = 'normal' THEN RAISE INFO 'processing asset_id = %', _asset_id; SELECT ARRAY(SELECT id FROM account_asset_depreciation_line dl WHERE dl.asset_id=_asset_id AND type = 'create' ORDER BY type, line_date) INTO _dl_ids; IF ARRAY_LENGTH(_dl_ids, 1) IS NULL THEN RAISE INFO 'creating init entry for asset_id = %', _asset_id; SELECT * FROM account_asset_depreciation_line dl WHERE dl.asset_id=_asset_id AND type = 'depreciate' ORDER BY type, line_date LIMIT 1 INTO _aadl; INSERT INTO account_asset_depreciation_line (create_uid, create_date, asset_id, name, move_check, line_date, amount, init_entry, type) VALUES (_aadl.create_uid, _aadl.create_date, _asset_id, replace(_aadl.name, '/1', '/0'), false, _asset.date_start, _asset.asset_value, true, 'create') RETURNING id INTO _init_id; END IF; END IF; _asset_index := _asset_index + 1; END LOOP; END $$ LANGUAGE plpgsql; 8) update account_asset_depreciation_line line_date field --------------------------------------------------------- /* plpgsql script to upgrade the account_asset_depreciation_line table for the account_asset 2.x version This script will move the depreciation lines to the last day of the month Author : noviat (www.noviat.com) */ DO $$ DECLARE _max_records INTEGER := 200; _asset_index INTEGER := 1; _asset_id INTEGER; _asset_ids INTEGER[]; _asset account_asset_asset%ROWTYPE; _dl_ids INTEGER[]; _dl_id INTEGER; _aadl account_asset_depreciation_line%ROWTYPE; _init_id INTEGER; _new_date DATE; BEGIN SELECT ARRAY(SELECT id FROM account_asset_asset ORDER BY id ASC) INTO _asset_ids; RAISE INFO 'asset_ids = %', _asset_ids; IF array_length(_asset_ids, 1) < _max_records THEN _max_records = array_length(_asset_ids, 1); END IF; WHILE _asset_index <= _max_records LOOP _asset_id = _asset_ids[_asset_index]; SELECT * FROM account_asset_asset WHERE id = _asset_id INTO _asset; IF _asset.type = 'normal' THEN RAISE INFO 'processing asset_id = %', _asset_id; SELECT ARRAY(SELECT id FROM account_asset_depreciation_line dl WHERE dl.asset_id=_asset_id AND type = 'depreciate' ORDER BY line_date) INTO _dl_ids; RAISE INFO 'processing _dl_ids = %', _dl_ids; IF ARRAY_LENGTH(_dl_ids, 1) IS NOT NULL THEN FOR i IN array_lower(_dl_ids, 1) .. array_upper(_dl_ids, 1) LOOP _dl_id = _dl_ids[i]; RAISE INFO 'processing dl_id = %', _dl_id; SELECT (date_trunc('MONTH', line_date) + INTERVAL '1 MONTH - 1 day')::date FROM account_asset_depreciation_line dl WHERE dl.id=_dl_id into _new_date; RAISE INFO '_new_date = %', _new_date; UPDATE account_asset_depreciation_line SET line_date = _new_date WHERE id=_dl_id; END LOOP; END IF; END IF; _asset_index := _asset_index + 1; END LOOP; END $$ LANGUAGE plpgsql; /* adjust also associated accounting entry dates */ UPDATE account_move m SET date=sq.line_date FROM (SELECT dl.line_date, m.id FROM account_asset_depreciation_line dl LEFT OUTER JOIN account_move m ON dl.move_id=m.id WHERE dl.line_date != m.date) sq WHERE m.id=sq.id; UPDATE account_move_line l SET date=sq.date FROM (SELECT m.date, l.id FROM account_move_line l JOIN account_move m ON l.move_id=m.id WHERE l.date != m.date) sq WHERE l.id=sq.id; 9) update asset & asset categories method & method time ------------------------------------------------------- e.g. UPDATE account_asset_category SET method_time='year'; UPDATE account_asset_category SET method_period='month'; UPDATE account_asset_asset SET method_time='year'; UPDATE account_asset_history SET method_time='year'; UPDATE account_asset_asset SET method_period='month'; 10) fix rounding errors ----------------------- e.g. UPDATE account_asset_depreciation_line SET amount=round(amount,2); UPDATE account_asset_depreciation_line SET remaining_value=round(remaining_value,2); UPDATE account_asset_depreciation_line SET depreciated_value=round(depreciated_value,2); 11) create assets of type 'view' and set parent_id on assets of type 'normal' ----------------------------------------------------------------------------- create 'type view' assets (required for reporting) and complete the parent_id field via PSQL commands for the 'type normal' assets. e.g. UPDATE account_asset_asset SET parent_id = 1024 WHERE type='normal' AND parent_id IS NULL AND category_id=1; UPDATE account_asset_asset SET parent_id = 1025 WHERE type='normal' AND parent_id IS NULL AND category_id=2; UPDATE account_asset_asset SET parent_id = 1026 WHERE type='normal' AND parent_id IS NULL AND category_id=3; 12) update account_move_line ---------------------------- /* plpgsql script to set asset_id on depreciation account move lines Author : noviat (www.noviat.com) */ DO $$ DECLARE _asset account_asset_asset%ROWTYPE; _aadl account_asset_depreciation_line%ROWTYPE; _aml account_move_line%ROWTYPE; BEGIN FOR _asset IN (SELECT * FROM account_asset_asset ORDER BY id ASC) LOOP RAISE INFO 'updating depreciation account.move.line for asset_id = %', _asset.id; FOR _aadl IN (SELECT * FROM account_asset_depreciation_line WHERE asset_id = _asset.id AND type='depreciate' ORDER BY line_date) LOOP IF _aadl.move_id IS NOT NULL THEN FOR _aml IN (SELECT * FROM account_move_line WHERE move_id = _aadl.move_id AND asset_id IS NULL) LOOP RAISE INFO 'Updating aml_id = %s', _aml.id; UPDATE account_move_line SET asset_id = _asset.id WHERE id = _aml.id; END LOOP; END IF; END LOOP; END LOOP; END $$