Posts Tagged ‘SQL’

Oracle: Update From equivalent

update statement

Quick note on how to update data in a series of joined tables using a subquery in the UPDATE statement in Oracle, kind of like the UPDATE FROM in SqlServer.

First of all check out the above diagram, I’ve stolen it from this link: http://download.oracle.com/docs/cd/B19306_01/appdev.102/b14261/update_statement.htm which also gives you more information on the UPDATE statement.

So what this says is that we can update on a table alias/subquery , which could contain our data set made from a  series of joins such as the code snippet below:

update (select
            tb5.stock_level
                                from
                                    schema1.table1 tb1,
                                    schema1.table2 tb2,
                                    schema1.table3 tb3,
                                    schema1.table4 tb4,
            schema2.table1 tb5
                                where
                                    tb1.id = tb2.id AND
                                    tb2.prod_id = tb3.prod_id AND
                                    tb3.sku_id = tb4.sku_id AND
                                    tb4.sku_id NOT IN (SELECT sku_id FROM schema1.table6) AND
            tb5.ref_id = tb4.sku_id AND
                                    tb1.country_iso_code = 'GB') mySubQuery
set mySubQuery.stock_level = 0

[ad#Google Ad in content]
Basically the same layout as doing subqueries with a SELECT statement, however, there are a few things to note. First of all if you use a SELECT DISTINCT in your subquery you’ll get an Oracle error ORA-01732 mentioning something about data manipulation not being legal for your table view. Next you may find that you get another error  ORA-01779 which is something about modifying a column which maps to a non key-preserved table.

While the above syntax is legal and you can get around the latter error, providing your constraints and foreign keys are declared on your database correctly, a better way to achieve updating records in a joined subquery is to use the WHERE IN clause on your UPDATE statement as below:

UPDATE schema2.table1
SET    schema2.table1.stock_level = 0
WHERE  schema2.table1.ref_id IN (select
            tb4.sku_id
                                from
                                    schema1.table1 tb1,
                                    schema1.table2 tb2,
                                    schema1.table3 tb3,
                                    schema1.table4 tb4,
            schema2.table1 tb5
                                where
                                    tb1.id = tb2.id AND
                                    tb2.prod_id = tb3.prod_id AND
                                    tb3.sku_id = tb4.sku_id AND
                                    tb4.sku_id NOT IN (SELECT sku_id FROM schema1.table6) AND
            tb5.ref_id = tb4.sku_id AND
                                    tb1.country_iso_code = 'GB')

Seems just as quick and works (0.14 seconds for 2000 updates out of a 50000+ across separate schemas). Also handy if you dont have access to fix the database constraints etc… (Or if you don’t know how).

Writing basic case switch statements in Oracle PL/SQL

Oracle CASE

This is the equivalent code for writing a switch statement in Oracle. In Oracle to do the switch we use a function called case. Which looks for a value in the field specified, when it returns true it returns a value else returns a default. This has the same logic as writing an if statement pretty much, e.g. IF (value == “bob”) { do stuff } ELSE….

This is very very handy when having to do some reports and for instance the categories in your database don’t match up to what the report needs or you need combine a few columns together based on their values.

When writing a CASE typically it should be a part of your SELECT columns statement as below. We start it by declaring a CASE, and then a WHEN clause, so when value = xxx THEN do this…

SELECT
table.*,
CASE
  WHEN table.column_name = 'me' THEN 'yes'
  WHEN table.column_name = 'you' THEN 'no'
  ELSE 'neither'
END AS "Me or You"
FROM
table
WHERE ...

So when the value in our column equals ‘me’ then the value output in the results will be ‘yes’. We use the ELSE line to return a default if no WHEN clause is matched. We then end our CASE with END and then we can assign a name to this column using the AS command. Otherwise your column will be named as the entire CASE function which isn’t really that handy.

You can add multiple clauses just like a basic WHERE query on your WHEN clause for example:

  WHEN tableA.column_name = 'me' AND tableB.column_name = 'myself' THEN 'yes'

This is pretty handy when you want to base a case on multiple tables or columns and of course you can use OR, IS NOT etc… in the WHEN clause. For the THEN part you can also return another column instead of an arbitary value. So:

  WHEN tableA.column_name = 'me' AND tableB.column_name = 'myself' THEN tableC.column_some_name

And finally instead of just referring to a pre-defined column name from our tables we can write a SQL SELECT statement for the WHEN clause which is very handy when we want to switch on a record count for instance:

SELECT
column_name,
CASE
  WHEN (SELECT COUNT(tableD.column_name) FROM tableD WHERE column_name = 'me') > 0 THEN 'Yes'
  ELSE 'No'
END AS "me"
FROM
...

Spool a CSV file from Oracle/ SQL*Plus without quotes

oracle spool csv

Quite useful, I had the case where I needed to provide a CSV file to an external party from our Oracle 10g database. No problem, there are loads of CSV export tools out there. But it then transpired that the CSV’s that I was generating were using quote (“) marks to identify fields e.g. “field1″,”field2” and so on…

When I ran the script in something like SQL Developer it would spool the file and also spool the query as well into the file no matter what I specified. Along with this it also wouldn’t recognise usage of variables in SQL Developer. Basically what I’m saying here is write the query in something like SQL Developer by all means but for writting and debugging a CSV spooler etc… just save the hassle and go straight to SQL*Plus.

First of all lets start with how to spool the CSV file without leading line breaks, no quote marks etc… the below is the SQL script to run, we’ll need to save this in order to run it later.

[ad#Google Ad in content]

set echo off
set verify off
set termout on
set heading off
set pages 50000
set feedback off
set newpage none
set linesize 160
spool /path/save/file/myFile.csv
SELECT 'Field1Name,Field2Name,Field3Name,Field4Name,Field5Name' from dual;
SELECT
field1||','||
field2||','||
field3||','||
field4||','||
field5
FROM
table1
WHERE
field1='etc...';
spool off;
exit;

We first set any settings we need at the start for the script these are as follows:

set echo off [Won’t display any SQL commands that are run]
set verify off [If turned on, it prints out each defined variable twice]
set termout on [Supresses the output of SQL commands but not the commands themselves]
set heading off [Sets whether column headings are outputted or not]
set pages 50000 [50000 lines without a page break, basically sets the height of the page]
set feedback off [If on it will feedback to user e.g. table created, row deleted etc..]
set newpage none [Removes any leading/ blank lines at the start of a page]
set linesize 200 [Sets the width of a line]

[ad#Google Ad in content]

We then start to build our file by calling the spool function with the directory of where to save the file and the file name. To get our headings or column names we then do a simple select statement on dual where each item will be what we want the column to be named – basically to print out the headings to the spool file. We could of course just set heading to ‘on’ and get the column names, but then column names are not always that useful.

We then run our query as normal, the only thing to note is the use of ||’,’|| which instead of double quotes it will still get used as the field separator, you can use ; or tabs for instance instead. The || || is actually used in Oracle for concatenation of fields to allow 2 strings to be used with an additional element imbetween – it also saves us writing CONCAT() for every 2 strings/ columns. If you do not specify¬†this parameter after each column you select then the default double quotes will be used around your fields. We then turn spool off and then exit so when our .sql file is run it will stop and break the connection.

That’s our SQL script, we want to run this script in command prompt because we can launch SQL*Plus with various parameters and switches, the one we need here is silent,¬† -s, which tells SQL*Plus not to show the dialogue and thus not to spool it.

The command to run your script will then be something like:

sqlplus -s {schema_name}/{schema_pwd}@{service_name} @test.sql

That lauches SQL*Plus in silent mode, connects to your schema and then runs the .sql script spooling your .csv file and finally exiting SQL*Plus.

Quick note, if you want to append your filename with todays date for instance then you can do something like the below where we assign the date to a variable, &mydate and set it with the value from your databases sysdate.

...
set linesize 160
column dcol new_value mydate noprint
select to_char(sysdate,'YYYYMMDD') dcol from dual;
spool /path/to/save/file/&mydate.myFile.csv
SELECT 'Field1Name,Field2Name,Field3Name,Field4Name,Field5Name' from dual;
...

LIMIT equivalent for Oracle

So you use MySQL etc… and you’re used to adding a LIMIT clause to your query for example,

SELECT * FROM table WHERE name = ‘bob’ LIMIT 1

And now you’re using Oracle and want to do the same thing? But it throws some dread ORA error – why?

Well because Oracle doesn’t have LIMIT, thats why!

So instead we have ROWNUM and using this instead we can do pretty much the same thing by adding an AND to the where clause as thus:

SELECT * FROM table WHERE name = ‘bob’ AND rownum = 1

This also means we can do < 10, > 10 etc…

And thats what I learnt in Oracle land today.