Thread: Query RE using COPY
I use the COPY command to load data from a file into tables in my database. The following is an example done in psql:COPY deals_temp_load FROM 'c:/temp/autodrs_deals.txt' WITH DELIMITER AS '^' QUOTE '\f' CSV HEADER; If a column is added to the table but has not been added to the extracts which create the autodrs_deals.txt file, this errors thusly: ERROR: missing data for column "location" CONTEXT: COPY deals_temp_load, line 2: "line containing data removed for confidentiality - suffice to say it does not contain the 'location' column" Is there any way of telling it to ignore columns that have not been specified in the file used to load? I have tried giving the column a default value but I still get the error. The column in this case 'location' is a nullable column and does not always have data (yes, bad design for a database, but we'll skip that point for now) thus I am not concerned if the load procedure doesn't supply it. BTW, this is done on Weendoze. Thanks, Paul. -- Paul Lambert Database Administrator AutoLedgers
COPY mytbl (col1, col2, col3, col4, col6) FROM 'myfile.txt' WITH DELIMITER AS '^' QUOTE '\f' CSV HEADER; On 5/7/07, Paul Lambert <paul.lambert@autoledgers.com.au> wrote: > I use the COPY command to load data from a file into tables in my database. > > The following is an example done in psql: > COPY deals_temp_load FROM 'c:/temp/autodrs_deals.txt' WITH DELIMITER AS > '^' QUOTE '\f' CSV HEADER; > > If a column is added to the table but has not been added to the extracts > which create the autodrs_deals.txt file, this errors thusly: > ERROR: missing data for column "location" > CONTEXT: COPY deals_temp_load, line 2: "line containing data removed > for confidentiality - suffice to say it does not contain the 'location' > column" > > Is there any way of telling it to ignore columns that have not been > specified in the file used to load? I have tried giving the column a > default value but I still get the error. The column in this case > 'location' is a nullable column and does not always have data (yes, bad > design for a database, but we'll skip that point for now) thus I am not > concerned if the load procedure doesn't supply it. > > BTW, this is done on Weendoze. > > Thanks, > Paul. > > -- > Paul Lambert > Database Administrator > AutoLedgers > > > ---------------------------(end of broadcast)--------------------------- > TIP 9: In versions below 8.0, the planner will ignore your desire to > choose an index scan if your joining column's datatypes do not > match > -- Jonah H. Harris, Software Architect | phone: 732.331.1324 EnterpriseDB Corporation | fax: 732.331.1301 33 Wood Ave S, 3rd Floor | jharris@enterprisedb.com Iselin, New Jersey 08830 | http://www.enterprisedb.com/
Jonah H. Harris wrote: > COPY mytbl (col1, col2, col3, col4, col6) FROM 'myfile.txt' WITH > DELIMITER AS '^' QUOTE '\f' CSV HEADER; > > I would rather not do it this way as I use the same load script at all customer sites where the extracts and requirements may vary. I.e. one customer may not use the location field mentioned above, but another might. What I would prefer to do, if possible, is set that column in the database to 'not required' so that if I get an extract that doesn't have that column in the file, the copy doesn't care. As it stands now I generally have to drop all the unneeded columns from numerous tables, perform my load and then re-addthem back again. When we're talking about 40 or more tables in each database some tables with several hundred columns... your suggestion would be a bit cumbersome - particularly if it is only one or two columns in each table that that the client doesn't need. -- Paul Lambert Database Administrator AutoLedgers
Can you modify the 'extract' and make the extra column "\n" which is the null escape? That would be the only other option. -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Paul Lambert Sent: Tuesday, 8 May 2007 12:44 To: pgsql-sql@postgresql.org Subject: Re: [SQL] Query RE using COPY Jonah H. Harris wrote: > COPY mytbl (col1, col2, col3, col4, col6) FROM 'myfile.txt' WITH > DELIMITER AS '^' QUOTE '\f' CSV HEADER; > > I would rather not do it this way as I use the same load script at all customer sites where the extracts and requirements may vary. I.e. one customer may not use the location field mentioned above, but another might. What I would prefer to do, if possible, is set that column in the database to 'not required' so that if I get an extract that doesn't have that column in the file, the copy doesn't care. As it stands now I generally have to drop all the unneeded columns from numerous tables, perform my load and then re-addthem back again. When we're talking about 40 or more tables in each database some tables with several hundred columns... your suggestion would be a bit cumbersome - particularly if it is only one or two columns in each table that that the client doesn't need. -- Paul Lambert Database Administrator AutoLedgers ---------------------------(end of broadcast)--------------------------- TIP 6: explain analyze is your friend *******************Confidentiality and Privilege Notice******************* The material contained in this message is privileged and confidential to the addressee. If you are not the addressee indicated in this message or responsible for delivery of the message to such person, you may not copy or deliver this message to anyone, and you should destroy it and kindly notify the sender by reply email. Information in this message that does not relate to the official business of Weatherbeeta must be treated as neither given nor endorsed by Weatherbeeta. Weatherbeeta, its employees, contractors or associates shall not be liable for direct, indirect or consequential loss arising from transmission of this message or any attachments
Phillip Smith wrote: > Can you modify the 'extract' and make the extra column "\n" which is the > null escape? > > That would be the only other option. > > Right now the software that does the extracts is developed by our applications developers, but I'll be taking that onto my side in the near future, just looking for a workaround until then. -- Paul Lambert Database Administrator AutoLedgers
On 5/8/07, Paul Lambert <paul.lambert@autoledgers.com.au> wrote: > Right now the software that does the extracts is developed by our > applications developers, but I'll be taking that onto my side in the > near future, just looking for a workaround until then. Sorry, but there isn't one. An unqualified COPY expects all columns and the syntax I gave you is the only way to limit the columns for insertion. You could write your own server-side function to parse, split, and insert the data, but it would be slower than COPY. Likely, the easiest thing would be to change your company's software. -- Jonah H. Harris, Software Architect | phone: 732.331.1324 EnterpriseDB Corporation | fax: 732.331.1301 33 Wood Ave S, 3rd Floor | jharris@enterprisedb.com Iselin, New Jersey 08830 | http://www.enterprisedb.com/