Beefy Boxes and Bandwidth Generously Provided by pair Networks
Perl: the Markov chain saw
 
PerlMonks  

Re^3: [OT] MySQL recalibrating a sort-index

by erix (Prior)
on Feb 16, 2018 at 20:53 UTC ( [id://1209334]=note: print w/replies, xml ) Need Help??


in reply to Re^2: [OT] MySQL recalibrating a sort-index
in thread [OT] MySQL recalibrating a sort-index

Yeah, the other way is more general: create, then join to a temporary table. (that floor() was just a first try, I should have removed it)

insert into $t values (394, 2, '*Inserted 1st*', :insert_location); -- update $t set f_sort = floor(f_sort)+1 where f_sort >= :insert_loca +tion; -- meh -- instead: -- create temporary table create temp table _t as select f_node_id, f_sort, row_number() over () as new_number from ( select f_node_id, f_sort from $t order by f_sort ) as f order by new_number ; -- update table update $t t set f_sort = _t.new_number from _t where _t.f_node_id = t.f_node_id --> join expression and _t.new_number <> t.f_sort --> avoid unnecessary writes ; drop table _t; --> remove temp table

It's verbose-ugly but it works without repeating the values.

Replies are listed 'Best First'.
Re^4: [OT] MySQL recalibrating a sort-index
by LanX (Saint) on Feb 16, 2018 at 23:34 UTC
Re^4: [OT] MySQL recalibrating a sort-index
by LanX (Saint) on Feb 16, 2018 at 22:43 UTC
    I haven't tested it yet, but why does an UPDATE from a temp table have no conflict with the UNIQUEness of f_sort (see the UPDATE in the OP)?

    Cheers Rolf
    (addicted to the Perl Programming Language and ☆☆☆☆ :)
    Wikisyntax for the Monastery

      Ah, you were looking for a DEFERRABLE CONSTRAINT, which postpones the constraint-validation to the end of a transaction.

      So, you'd do (again, postgres):

      create table tree ( f_node_id int primary key , f_parent_id int , f_name text , f_sort float , constraint tree_parent_sort_uniq_idx unique (f_parent_id, f_sort) d +eferrable );

      This lets you mess about with non-unique states for the duration of a transaction. The constraint (here: uniqueness) is only then enforced.

      I can't imagine MariaDB does not have this functionality but I can't find it in the documentation. (I looked for DEFERRED or DEFERRABLE. The MariaDB docs list 'DEFERRED' as a reserved word but I see no functionality associated with it.)

Log In?
Username:
Password:

What's my password?
Create A New User
Domain Nodelet?
Node Status?
node history
Node Type: note [id://1209334]
help
Chatterbox?
and the web crawler heard nothing...

How do I use this?Last hourOther CB clients
Other Users?
Others surveying the Monastery: (6)
As of 2024-04-18 20:00 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?

    No recent polls found