Skip to end of metadata
Go to start of metadata

You are viewing an old version of this page. View the current version.

Compare with Current View Page History

« Previous Version 20 Next »


Prepare the Input Data

The Bulk Loader can load data into the EAS from either a shapefile or comma-separated value (CSV) file, and is run on the ETL server as a job.py job.  Currently, the ETL server is running the Windows operating system.

Shapefile

Ensure that your shapefile has a defined projection of NAD 1983 StatePlane California III FIPS 0403 Feet (EPSG 102643) before attempting to load it into EAS.

Shapefiles must be named bulkload.shp and placed in the following directory on the ETL server:

C:\apps\eas_automation\app_data\data\bulkload_shapefile

Input shapefiles require the following schema:

field namedata typelength
OBJECTIDinteger9
blockstring80
lotstring80
unitstring80
unit_sfxstring80
st_numinteger4
st_num_sfxstring20
st_namestring32
st_suffix*string10
st_typestring4
sourcestring32
st_prefixstring

10

Examples

addressblocklotunitunit_sfxst_numst_num_sfxst_namest_suffix*st_typest_prefix
1 SOUTH VAN NESS AVE
3506001

1
VAN NESS

AVESOUTH
20 25TH AVE NORTH1301018

20
25THNORTHAVE

127 A CENTRAL AVE

1233

007



127ACENTRAL
AVE
5900 03RD ST 22175431B0932217
5900
03RD
ST
100 BROADWAY0141003B

100
BROADWAY


200 MAIN ST (APARTMENT) 2D37390082D200
MAIN
ST

Comma-separated Value (CSV) file

CSV files must be named bulkload_data.csv and placed in the following directory on the ETL server:

C:\apps\eas_automation\app_data\data

Input CSV files require the following schema:

field namedata typelength
blockstring256
lotstring256
unitstring256
unit_sfxstring256
street_numberstring

256

street_number_sfxstring256
street_namestring256
street_sfx*string256
street_typestring256
load_sourcestring32

Examples

addressblocklotunitunit_sfxstreet_numberstreet_number_sfxstreet_namestreet_sfx*street_type
1 SOUTH VAN NESS AVE
3506001

1
SOUTH VAN NESS

AVE
20 25TH AVE NORTH1301018

20
25THNORTHAVE

127 A CENTRAL AVE

1233

007



127ACENTRAL
AVE
5900 03RD ST 22175431B0932217
5900
03RD
ST
100 BROADWAY0141003B

100
BROADWAY

200 MAIN ST (APARTMENT) 2D37390082D200
MAIN
ST


* Use this field for streets that have a Street Name Post Directional, for example the "North" in "25th Ave North".

Prepare the Output Table

The Bulk Loader will produce an output table (bulkloader.address_extract) that contains, among other information, the disposition of each input address record that was submitted to the Bulk Loader.  The output table may already have records in it for any of the following reasons:

  • The Bulk Loader was just run and the shapefile or CSV file contained at least one address record in it, and so the output table contains at least one result record.
  • The database in the current environment (for example DEV) was restored from the database in another environment (for example PROD), and the output table from the other environment (PROD) contained result records from a bulk-load that was performed in that environment (PROD).  Please see the page Restoring for detailed instructions for performing such a database restoration.

If you do not want these existing records to be considered in your upcoming bulk-load attempt, then these records should be deleted prior to running your bulk-load by following these steps:

  1. Establish your SSH tunnel to the target EAS database server.
  2. Invoke pgAdmin and navigate to the target database, and then the output table (bulkloader.address_extract).
  3. Right-click the output table and invoke the Query Tool.
  4. Remove leftover records from the previous Bulk Loader iteration.

    TRUNCATE bulkloader.address_extract, bulkloader.blocks_nearest;
  5. Run garbage collection to free disk space held by truncated tuples.

    VACUUM FULL ANALYZE bulkloader.address_extract;
    VACUUM FULL ANALYZE bulkloader.blocks_nearest;
  6. Optional: count all records in the database for use in a before/after record count comparison.

    SELECT schemaname,relname,n_live_tup FROM pg_stat_user_tables ORDER BY schemaname,relname,n_live_tup;

Run the Bulk Loader

The Bulk Loader is run on the ETL server, and depending on the number of address records that are going to be processed, the Bulk Loader will complete its work at any time from a few minutes, to a few hours.  The following table contains some information for some typical runs.

environmenttyperecordsstagebulk load
SF_DEVshapefile5587-9 seconds30-130 seconds
SF_DEVshapefile49,98025 seconds5 minutes


  1. Remote desktop (RDP) into the ETL server.
  2. Move to the directory that contains the file job.py.

    cd C:\apps\eas_automation\automation\src
  3. Stage the input data.

    Shapefile Input Format
    python job.py --job stage_bulkload_shapefile --env <environment> --action EXECUTE
    CSV Input Format
    python job.py --job stage_bulkload_csv --env <environment> --action EXECUTE
  4. Run the bulkload job.

    python job.py --job bulkload --env <environment> --action EXECUTE

Evaluate the Results

Evaluate 'bulkloader' schema

Evaluate the results of the bulk-load by opening the database and inspecting the output table bulkloader.address_extract for values in the field exception_text

  1. Addresses that were successfully bulk-loaded will have a date in the field load_tms and a NULL value in the field exception_text.

    -- Count records successfully bulk-loaded:
    SELECT COUNT(*)
    FROM bulkloader.address_extract
    WHERE NOT(load_tms IS NULL) AND (exception_text IS NULL);
    
    -- View records successfully bulk-loaded:
    SELECT *
    FROM bulkloader.address_extract
    WHERE NOT(load_tms IS NULL) AND (exception_text IS NULL);
  2. The presence of exception text indicates a problem with the source data.

    -- Count records with exception:
    SELECT COUNT(*)
    FROM bulkloader.address_extract
    WHERE NOT(exception_text IS NULL);
    
    -- View records with exception:
    SELECT *
    FROM bulkloader.address_extract
    WHERE NOT(exception_text IS NULL);
    
    -- View totals for each distinct 'exception_text' value
    SELECT exception_text, Count(*) 
    FROM bulkloader.address_extract
    GROUP BY exception_text
    ORDER BY exception_text;
  3. To rectify bulk-load exceptions, do not correct any exception records in the output table bulkloader.address_extract. Instead, correct the corresponding records in the source data and then re-run the Bulk Loader.
  4. If block and lot values were included in the input data, a value should be found in the field address_x_parcel_id. Run the query below to find any records that had block and lot input values but did not get assigned a value for address_x_parcel_id.

    -- Count records where block and lot were provided but no address_x_parcel was assigned:
    SELECT COUNT(*) FROM bulkloader.address_extract
    WHERE (NOT (block IS NULL) OR NOT (block IS NULL))
    AND address_x_parcel_id IS NULL;
  5. Base addresses that were submitted by the Bulk Loader but were already in the EAS are indicated by values in the fields address_base_id and load_tms, and NULL values in the fields std_unit, street_segment, zone_id, address_id and exception_text.

    -- Count base addresses that were already in the EAS:
    SELECT COUNT(*)
    FROM bulkloader.address_extract
    WHERE NOT(address_base_id IS NULL)
          AND NOT(load_tms IS NULL)
          AND (std_unit IS NULL)
          AND (street_segment_id IS NULL)
          AND (zone_id IS NULL)
          AND (address_id IS NULL)
          AND (exception_text IS NULL);
    
    -- View base addresses that were already in the EAS:
    SELECT *
    FROM bulkloader.address_extract
    WHERE NOT(address_base_id IS NULL)
          AND NOT(load_tms IS NULL)
          AND (std_unit IS NULL)
          AND (street_segment_id IS NULL)
          AND (zone_id IS NULL)
          AND (address_id IS NULL)
          AND (exception_text IS NULL);
  6. Count and view new base addresses by looking for non-NULL values in the street_segment_id field. Cross-check with the 'public' schema by counting new 'public.address_base' records as shown below in Evaluate 'public' schema.

    -- Count base addresses that were not already in the EAS:
    SELECT COUNT(*)
    FROM bulkloader.address_extract
    WHERE NOT (street_segment_id IS NULL);
    
    -- View base addresses that were not already in the EAS:
    SELECT *
    FROM bulkloader.address_extract
    WHERE NOT (street_segment_id IS NULL);
  7. Evaluate records with non-NULL address_id values to count/view unit addresses that were added to the EAS.

    -- Count unit addresses added to the EAS:
    SELECT COUNT(*)
    FROM bulkloader.address_extract
    WHERE NOT (address_id IS NULL);
    
    -- View unit addresses added to the EAS:
    SELECT *
    FROM bulkloader.address_extract
    WHERE NOT (address_id IS NULL);

Evaluate 'public' schema

Evaluate tables in the public schema to cross-check record counts from the bulkloader schema evaluation.

  1. Find the change_request_id of the most recent bulk load.

    -- Get the change_request_id of the most recent bulk load:
    SELECT change_request_id
    FROM public.change_requests
    WHERE requestor_comment LIKE 'bulk load change request'
    ORDER BY change_request_id DESC
    LIMIT 1;
    
    -- Make note of this id for the queries in the subsequent steps.
  2. Count and view new base addresses associated with the change request.

    -- Count new base addresses
    SELECT COUNT (*)
    FROM public.addresses
    WHERE activate_change_request_id = change_request_id_goes_here
    AND unit_num IS NULL;
    
    -- View new base addresses
    SELECT *
    FROM public.addresses
    WHERE activate_change_request_id = change_request_id_goes_here
    AND unit_num IS NULL;
  3. Count and view new unit addresses associated with the change request.

    --- Count new unit addresses
    SELECT COUNT (*)
    FROM public.addresses
    WHERE activate_change_request_id = change_request_id_goes_here
    AND NOT unit_num IS NULL;
    
    -- View new unit addresses
    SELECT *
    FROM public.addresses
    WHERE activate_change_request_id = change_request_id_goes_here
    AND NOT unit_num IS NULL;
  4. Count and view all new 'public.addresses' records associated with the change request.

    -- Count all new addresses
    SELECT COUNT (*)
    FROM public.addresses
    WHERE activate_change_request_id = change_request_id_goes_here;
    
    -- View all new addresses
    SELECT *
    FROM public.addresses
    WHERE activate_change_request_id = change_request_id_goes_here;
  5. Count and view new 'public.address_base' records added to the EAS. Cross-check with the 'bulkloader' schema as shown above in Evaluate 'bulkloader' schema.

    -- Count new 'public.address_base' records
    SELECT COUNT(*) FROM public.address_base, public.addresses
    WHERE public.address_base.address_base_id = public.addresses.address_base_id
    AND public.addresses.address_base_flg = TRUE
    AND public.addresses.activate_change_request_id = change_request_id_goes_here;
    
    -- View new 'public.address_base' records
    SELECT activate_change_request_id, address_id, public.address_base.*
    FROM public.address_base, public.addresses
    WHERE public.address_base.address_base_id = public.addresses.address_base_id
    AND public.addresses.address_base_flg = TRUE
    AND public.addresses.activate_change_request_id = change_request_id_goes_here;
  6. Optional: count all records in the database for use in a before/after record count comparison.

    SELECT schemaname,relname,n_live_tup FROM pg_stat_user_tables ORDER BY schemaname,relname,n_live_tup;

Free space after large Bulk Loader batches

After successful loading and evaluating large batches of addresses, clean up the database by truncating and vacuuming the the Bulk Loader output tables.

TRUNCATE bulkloader.address_extract, bulkloader.blocks_nearest;
VACUUM FULL ANALYZE bulkloader.address_extract;
VACUUM FULL ANALYZE bulkloader.blocks_nearest;


  • No labels

0 Comments

You are not logged in. Any changes you make will be marked as anonymous. You may want to Log In if you already have an account.