Subversion Repositories computer_asset_manager_v2

Rev

Go to most recent revision | Details | Last modification | View Log | RSS feed

Rev Author Line No. Line
63 rodolico 1
/*
2
   This is a helper script to import CAMP v1 to CAMP v2. There are some
3
   customizations for our purposes, but it is mainly generic.
4
*/
5
 
75 rodolico 6
/*
7
   You MUST be logged into the correct database before running this
8
   connect camp2;
9
*/
10
 
61 rodolico 11
/* This is used to map old ID's to new ones */
75 rodolico 12
create or replace table mapping (
61 rodolico 13
         tablename varchar(32) not null,
14
         old_id    int unsigned not null,
15
         new_id    int unsigned not null,
16
         primary key (tablename,old_id,new_id)
17
      );
18
 
19
/* ***************************************
20
    Users
21
*/
22
 
23
/* grab all users in old table and insert here with the "L" password */
75 rodolico 24
truncate table _users;
25
insert into _users (login,password,email,isAdmin,enabled,created,removed)
61 rodolico 26
   select
27
      if (instr(email,'@'), left(email,instr(email,'@')-1), email),
28
      '$2y$10$GWsjPDZWzCoNuD1lC34PDeyqnjSKI.QAevtRnxpjHpkMIZJJNvK8m',
29
      if (instr(email,'@'), email, concat(email, '@dailydata.net' )),
30
      0,
31
      isnull(removed_date),
32
      date(added_date),
33
      date( removed_date )
34
   from
35
      camp.login;
36
 
75 rodolico 37
update _users set isAdmin = 1 where login = 'admin';
63 rodolico 38
 
61 rodolico 39
/* Set up mapping between old and new users */
75 rodolico 40
insert into mapping ( tablename,new_id,old_id )
61 rodolico 41
   select 
42
      '_users',
75 rodolico 43
      _users._user_id,
61 rodolico 44
      camp.login.login_id
45
   from
75 rodolico 46
      _users
47
      join camp.login on (_users.login = camp.login.email);
61 rodolico 48
 
49
 
50
/* Update all user permissions to default */
75 rodolico 51
truncate table  _users_permissions;
52
insert into _users_permissions (_user_id,_permission_id, value )
61 rodolico 53
   select 
54
      _user_id,
55
      _permission_id,
56
      1
57
   from 
58
      _permissions 
59
      join _users
60
   where 
61
      _permissions.default_value = 1
62
      and _users._user_id not in (
63
         select 
64
            _users._user_id 
65
         from 
75 rodolico 66
            _users_permissions 
67
            join _users using (_user_id)
61 rodolico 68
         );
66 rodolico 69
 
70
update _users set restrictions = '[owner]
71
Vanduzen' where login = 'jbellah';
61 rodolico 72
 
66 rodolico 73
update _users set restrictions = '[owner]
74
Walder IP Law' where login = 'swalder';
75
 
76
 
61 rodolico 77
/* *************************************
78
   Owners
79
*/
80
 
81
/* add owners */
75 rodolico 82
truncate table owner;
83
insert into owner (name,created,removed)
61 rodolico 84
   select 
85
      name,
86
      date( added_date ),
87
      date( removed_date)
88
   from 
89
      camp.client;
90
 
91
/* Set up mapping between old and new owners */
75 rodolico 92
insert into mapping ( tablename,new_id,old_id )
61 rodolico 93
   select 
94
      'owner',
75 rodolico 95
      owner.owner_id,
61 rodolico 96
      camp.client.client_id
97
   from
75 rodolico 98
      owner
99
      join camp.client on (owner.name = camp.client.name);
61 rodolico 100
 
101
/* ************************************************* 
102
   Locations. This is a little different.
103
   We have several things in the old database which were put in there
104
   because location ownership was not different from device ownership
105
   Here, we're building a table to break them apart
106
*/
75 rodolico 107
create or replace table location_mapping (
61 rodolico 108
   old_value varchar(64),
109
   new_value varchar(64),
110
   primary key (old_value,new_value)
111
);
75 rodolico 112
insert into location_mapping(old_value,new_value) values ('NOC','Colocation NOC' );
113
insert into location_mapping(old_value,new_value) values ('Lori Bryant Office','Lori Bryant, CPA - Stemmons Towers');
114
insert into location_mapping(old_value,new_value) values ('DD Vanduzen','Vanduzen Dallas');
115
insert into location_mapping(old_value,new_value) values ('Lakewood Title Office','LWT Corp');
116
insert into location_mapping(old_value,new_value) values ('AppServe (Daily Data)','AppServe Technologies');
117
insert into location_mapping(old_value,new_value) values ('Staffmasters (Daily Data)','Staffmasters - Stemmons Towers');
61 rodolico 118
 
119
 
120
/*
121
   Now, we copy the ones which are NOT found in the above over directly
122
*/
75 rodolico 123
truncate table location;
124
insert into location (name,created,removed)
61 rodolico 125
   select
126
      name,
127
      date(added_date),
128
      date(removed_date)
129
   from
130
      camp.site
131
   where
132
      camp.site.site_id not in
133
         (
134
            select 
135
               camp.site.site_id
136
            from 
137
               camp.site,
138
               location_mapping
139
            where 
140
               camp.site.name like concat( '%',location_mapping.old_value, '%')
141
               and camp.site.name <> 'Colocation NOC'
142
         );
143
 
144
/* Set up mapping between old and new locations, except for the aliases */
75 rodolico 145
insert into mapping ( tablename,new_id,old_id )
61 rodolico 146
   select 
147
      'location',
75 rodolico 148
      location.location_id,
61 rodolico 149
      camp.site.site_id
150
   from
75 rodolico 151
      location
152
      join camp.site on (location.name = camp.site.name);
61 rodolico 153
 
154
 
155
/* 
156
   Finally, we get the stuff we ignored in location_mapping and work 
157
   with it. We don't add those sites, we just do a mapping for them
158
*/
75 rodolico 159
insert into mapping (tablename,new_id,old_id)
61 rodolico 160
   select
161
      'location',
75 rodolico 162
      location.location_id,
61 rodolico 163
      site2.site_id
164
   from
165
      location
166
      join (
167
         select 
168
            camp.site.site_id,
169
            camp.site.name,
170
            location_mapping.old_value,
171
            location_mapping.new_value
172
         from 
173
            camp.site,
75 rodolico 174
            location_mapping
61 rodolico 175
         where 
176
            camp.site.name like concat( '%',location_mapping.old_value, '%')
177
            and camp.site.name <> 'Colocation NOC'
75 rodolico 178
         ) site2 on (location.name = site2.new_value );
63 rodolico 179
 
180
/* clean up */
75 rodolico 181
drop table location_mapping;
61 rodolico 182
 
183
/* ***************************************
184
  Devices
185
*/
186
 
187
/* grab all that are marked as systems, no PCI cards */
75 rodolico 188
truncate table device;
189
insert into device (uuid,serial,name,created,removed)
61 rodolico 190
   select 
191
      if ( length( serial ) = 36, serial, null ) uuid,
192
      if ( length( serial ) < 36, serial, null ) serial,
193
      device.name,
194
      date( device.added_date ),
195
      date( device.removed_date)
196
   from
197
      camp.device
198
      join camp.device_type using ( device_type_id )
199
   where 
200
      device_type.show_as_system = 'Y';
201
 
202
/* Set up mapping between old and new device */
75 rodolico 203
insert into mapping ( tablename,new_id,old_id )
61 rodolico 204
   select 
205
      'device',
75 rodolico 206
      new.device_id,
207
      old.device_id
61 rodolico 208
   from
75 rodolico 209
      device new
210
      join camp.device old using (name);
61 rodolico 211
 
63 rodolico 212
/* ***************************************
213
  Devices
214
*/
75 rodolico 215
truncate table device_type;
216
insert into device_type (name,created)
63 rodolico 217
   select
218
      name,
66 rodolico 219
      date(added_date)
63 rodolico 220
   from
221
      camp.device_type
222
   where
223
      camp.device_type.show_as_system = 'Y';
224
 
75 rodolico 225
insert into mapping( tablename, new_id, old_id )
63 rodolico 226
   select
227
      'device_type',
75 rodolico 228
      new.device_type_id,
229
      old.device_type_id
63 rodolico 230
   from
75 rodolico 231
      device_type new
232
      join camp.device_type old using (name)
63 rodolico 233
   where
75 rodolico 234
      old.show_as_system = 'Y';
63 rodolico 235
 
236
/* *********************************************************
237
   Linkage Tables
238
*/
239
 
240
/* device_device */
75 rodolico 241
truncate table device_device;
242
insert into device_device (device_id,parent_id,created)
63 rodolico 243
   select
75 rodolico 244
      mapping.new_id,
63 rodolico 245
      parent.new_id,
66 rodolico 246
      date(now())
63 rodolico 247
   from
248
      camp.device
75 rodolico 249
      join mapping on (camp.device.device_id = mapping.old_id and mapping.tablename = 'device' )
63 rodolico 250
      join (
251
         select
252
            device.device_id,
253
            mapping.new_id
254
         from
255
            camp.device
75 rodolico 256
            join mapping on (camp.device.device_id = mapping.old_id and mapping.tablename = 'device')
63 rodolico 257
         ) parent on ( camp.device.part_of = parent.device_id )
258
   where
259
      camp.device.device_type_id in (select device_type_id from camp.device_type where show_as_system = 'Y')
260
      and camp.device.part_of is not null
261
      and camp.device.removed_date is null;
262
 
263
/* use following to verify this is working
264
 
265
select 
266
   device.name device,
267
   parent.name parent
268
from 
269
   device 
270
   join device_device using (device_id) 
271
   join device parent on (device_device.parent_id = parent.device_id) 
272
where 
273
   device.removed is null
274
order by parent.name,device.name;
275
 
276
*/
277
 
278
/* device_device_type */
279
 
75 rodolico 280
truncate device_device_type;
281
insert into device_device_type (device_id,device_type_id)
63 rodolico 282
   select
283
      mapping.new_id,
284
      map_type.new_id
285
   from
286
      camp.device
287
      join camp.device_type on (camp.device.device_type_id = camp.device_type.device_type_id)
75 rodolico 288
      join mapping on (camp.device.device_id = mapping.old_id and mapping.tablename = 'device')
289
      join mapping map_type on (camp.device_type.device_type_id = map_type.old_id and map_type.tablename = 'device_type' )
63 rodolico 290
;      
291
 
292
/* verify with the following query 
293
 
66 rodolico 294
select device.name,device_types from device join view_device_types using (device_id);
63 rodolico 295
 
296
*/
297
 
298
/* location_device */
299
truncate table location_device;
66 rodolico 300
insert into location_device ( location_id,device_id,created )
63 rodolico 301
   select
302
      map_type.new_id,
303
      mapping.new_id,
66 rodolico 304
      date(camp.site.added_date)
63 rodolico 305
   from
306
      camp.device
307
      join camp.site using (site_id)
75 rodolico 308
      join mapping on (camp.device.device_id = mapping.old_id and mapping.tablename = 'device')
309
      join mapping map_type on (camp.site.site_id = map_type.old_id and map_type.tablename = 'location' )
63 rodolico 310
;      
311
 
312
/* Verify with the following query 
313
 
314
select 
315
   device.name,
316
   location.name
317
from 
318
   device 
319
   join location_device using (device_id) 
320
   join location using (location_id);
321
 
322
*/
323
 
324
/* owner_device */
325
truncate table owner_device;
66 rodolico 326
insert into owner_device ( owner_id,device_id,created )
63 rodolico 327
   select
328
      map_type.new_id,
329
      mapping.new_id,
66 rodolico 330
      date(camp.device.added_date)
63 rodolico 331
   from
332
      camp.device
333
      join camp.site using (site_id)
334
      join camp.client using (client_id)
75 rodolico 335
      join mapping on (camp.device.device_id = mapping.old_id and mapping.tablename = 'device')
336
      join mapping map_type on (camp.client.client_id = map_type.old_id and map_type.tablename = 'owner' )
63 rodolico 337
;      
338
 
339
/* Verify with the following query
340
 
341
select owner.name owner, device.name device from owner join owner_device using (owner_id) join device using (device_id);
342
 
343
*/
344
 
345
 
346
/* owner_location */
347
truncate table owner_location;
66 rodolico 348
insert into owner_location ( owner_id,location_id,created )
63 rodolico 349
   select
350
      map_type.new_id,
351
      mapping.new_id,
66 rodolico 352
      date(camp.site.added_date)
63 rodolico 353
   from
354
      camp.site
355
      join camp.client using (client_id)
75 rodolico 356
      join mapping on (camp.site.site_id = mapping.old_id and mapping.tablename = 'location')
357
      join mapping map_type on (camp.client.client_id = map_type.old_id and map_type.tablename = 'owner' )
63 rodolico 358
   where
75 rodolico 359
      camp.site.name in (select name from location)
63 rodolico 360
;
361
 
362
/* Verify with one of the following queries, or, simply open the app
363
 
364
select owner.name owner, location.name location from owner join owner_location using (owner_id) join location using (location_id);
365
select * from view_device_location_owner_type limit 10;
366
 
367
*/
368
 
76 rodolico 369
 
370